# # Run this Tcl script to generate the sqlite.html file. # set rcsid {$Id: lang.tcl,v 1.9 2001/09/20 01:44:44 drh Exp $} puts { Query Language Understood By SQLite

SQL As Understood By SQLite

} puts "

(This page was last modified on [lrange $rcsid 3 4] GMT)

" puts {

The SQLite library understands most of the standard SQL language. But it does omit some features while at the same time adding a few features of its own. This document attempts to describe percisely what parts of the SQL language SQLite does and does not support.

In all of the syntax diagrams that follow, literal text is shown in bold blue. Non-terminal symbols are shown in italic red. Operators that are part of the syntactic markup itself are shown in black roman.

This document is just an overview of the SQL syntax implemented by SQLite. Many low-level productions are omitted. For detailed information on the language that SQLite understands, refer to the source code.

SQLite implements the follow SQL commands:

Details on the implementation of each command are provided in the sequel.

} proc Syntax {args} { puts {} foreach {rule body} $args { puts "" regsub -all < $body {%LT} body regsub -all > $body {%GT} body regsub -all %LT $body {} body regsub -all %GT $body {} body regsub -all {[]|[*?]} $body {&} body regsub -all "\n" [string trim $body] "
\n" body regsub -all "\n *" $body "\n\\ \\ \\ \\ " body regsub -all {[|,.*()]} $body {&} body regsub -all { = } $body { = } body regsub -all {STAR} $body {*} body puts "
" } puts {
" puts "$rule ::=$body
} } proc Operator {name} { return "$name" } proc Nonterminal {name} { return "$name" } proc Keyword {name} { return "$name" } proc Section {name {label {}}} { puts "\n
" if {$label!=""} { puts "" } puts "

$name

\n" } proc Example {text} { puts "
$text
" } Section {BEGIN TRANSACTION} createindex Syntax {sql-statement} { BEGIN [TRANSACTION []] } Syntax {sql-statement} { END [TRANSACTION []] } Syntax {sql-statement} { COMMIT [TRANSACTION []] } Syntax {sql-statement} { ROLLBACK [TRANSACTION []] } puts {

Beginning in version 2.0, SQLite supports transactions with rollback and atomic commit. However, only a single level of transaction is required. In other words, transactions may not be nested.

No changes can be made to the database except within a transaction. Any command that changes the database (basically, any SQL command other than SELECT) will automatically starts a transaction if when is not already in effect. Automatically stared transactions are committed at the conclusion of the command.

Transactions can be started manually using the BEGIN TRANSACTION command. Such transactions persist until a COMMIT or ROLLBACK or until an error occurs or the database is closed. If an error is encountered or the database is closed, the transaction is automatically rolled back. The END TRANSACTION command is a alias for COMMIT.

} Section COPY copy Syntax {sql-statement} { COPY FROM } puts {

The COPY command is an extension used to load large amounts of data into a table. It is modeled after a similar command found in PostgreSQL. In fact, the SQLite COPY command is specifically designed to be able to read the output of the PostgreSQL dump utility pg_dump so that data can be easily transferred from PostgreSQL into SQLite.

The table-name is the name of an existing table which is to be filled with data. The filename is a string or identifier that names a file from which data will be read. The filename can be the STDIN to read data from standard input.

Each line of the input file is converted into a single record in the table. Columns are separated by tabs. If a tab occurs as data within a column, then that tab is preceded by a baskslash "\" character. A baskslash in the data appears as two backslashes in a row.

When the input data source is STDIN, the input can be terminated by a line that contains only a baskslash and a dot:} puts "\"[Operator \\.]\".

" Section {CREATE INDEX} createindex Syntax {sql-statement} { CREATE INDEX ON ( [, ]* ) } {column-name} { [ ASC | DESC ] } puts {

The CREATE INDEX command consists of the keywords "CREATE INDEX" followed by the name of the new index, the keyword "ON", the name of a previously created table that is to be indexed, and a parenthesized list of names of columns in the table that are used for the index key. Each column name can be followed by one of the "ASC" or "DESC" keywords to indicate sort order, but the sort order is ignored in the current implementation.

There are no arbitrary limits on the number of indices that can be attached to a single table, nor on the number of columns in an index.

The exact text of each CREATE INDEX statement is stored in the sqlite_master table. Everytime the database is opened, all CREATE INDEX statements are read from the sqlite_master table and used to regenerate SQLite's internal representation of the index layout.

} Section {CREATE TABLE} {createtable} Syntax {sql-command} { CREATE TABLE ( [, ]* [, ]* ) } {column-def} { []* } {type} { | ( ) | ( , ) } {column-constraint} { NOT NULL | PRIMARY KEY [] | UNIQUE | CHECK ( ) | DEFAULT } {constraint} { PRIMARY KEY ( [, ]* ) | UNIQUE ( [, ]* ) | CHECK ( ) } puts {

A CREATE TABLE statement is basically the keywords "CREATE TABLE" followed by the name of a new table and a parenthesized list of column definitions and constraints. The table name can be either an identifier or a string. The only reserved table name is "sqlite_master" which is the name of the table that records the database schema.

Each column definition is the name of the column followed by the datatype for that column, then one or more optional column constraints. The datatype for the column is ignored. All information is stored as null-terminated strings. The constraints are also ignored, except that the PRIMARY KEY constraint will cause an index to be automatically created that implements the primary key and the DEFAULT constraint which specifies a default value to use when doing an INSERT.

There are no arbitrary limits on the number of columns or on the number of constraints in a table. The total amount of data in a single row is limited to 65535 bytes.

The exact text of each CREATE TABLE statement is stored in the sqlite_master table. Everytime the database is opened, all CREATE TABLE statements are read from the sqlite_master table and used to regenerate SQLite's internal representation of the table layout.

} Section DELETE delete Syntax {sql-statement} { DELETE FROM [WHERE ] } puts {

The DELETE command is used to remove records from a table. The command consists of the "DELETE FROM" keywords followed by the name of the table from which records are to be removed.

Without a WHERE clause, all rows of the table are removed. If a WHERE clause is supplied, then only those rows that match the expression are removed.

} Section {DROP INDEX} dropindex Syntax {sql-command} { DROP INDEX } puts {

The DROP INDEX statement consists of the keywords "DROP INDEX" followed by the name of the index. The index named is completely removed from the disk. The only way to recover the index is to reenter the appropriate CREATE INDEX command.

} Section {DROP TABLE} droptable Syntax {sql-command} { DROP TABLE } puts {

The DROP TABLE statement consists of the keywords "DROP TABLE" followed by the name of the table. The table named is completely removed from the disk. The table can not be recovered. All indices associated with the table are also deleted.

} Section EXPLAIN explain Syntax {sql-statement} { EXPLAIN } puts {

The EXPLAIN command modifier is a non-standard extension. The idea comes from a similar command found in PostgreSQL, but the operation is completely different.

If the EXPLAIN keyword appears before any other SQLite SQL command then instead of actually executing the command, the SQLite library will report back the sequence of virtual machine instructions it would have used to execute the command had the EXPLAIN keyword not been present. For additional information about virtual machine instructions see the architecture description or the documentation on available opcodes for the virtual machine.

} Section expression expr Syntax {expression} { | | | ( ) | | . | | ( | STAR ) | ISNULL | NOTNULL | [NOT] BETWEEN AND | [NOT] IN ( ) | [NOT] IN ( ) } {like-op} { LIKE | GLOB | NOT LIKE | NOT GLOB } puts {

This section is different from the others. Every other section of this document talks about a particular SQL command. This section does not talk about a standalone command but about "expressions" which are subcomponent of most other commands.

SQLite understands the following binary operators, in order from highest to lowest precedence:

*    /
+    -
<    <=   >    >=
=    ==   !=   <>   IN
AND
OR

Any SQLite value can be used as part of an expression. For arithmetic operations, integers are treated as integers. Strings are first converted to real numbers using atof(). For comparison operators, numbers compare as numbers and strings compare as strings. For string comparisons, case is significant but is only used to break a tie. Note that there are two variations of the equals and not equals operators. Equals can be either} puts "[Operator =] or [Operator ==]. The non-equals operator can be either [Operator !=] or [Operator {<>}].

" puts {

The LIKE operator does a wildcard comparision. The operand to the right contains the wildcards.} puts "A percent symbol [Operator %] in the right operand matches any sequence of zero or more characters on the left. An underscore [Operator _] on the right matches any single character on the left." puts {The LIKE operator is not case sensitive and will match upper case characters on one side against lower case characters on the other. (A bug: SQLite only understands upper/lower case for 7-bit Latin characters. Hence the LIKE operator is case sensitive for 8-bit iso8859 characters or UTF-8 characters. For example, the expression 'a' LIKE 'A' is TRUE but 'æ' LIKE 'Æ' is FALSE.)

The GLOB operator is similar to LIKE but uses the Unix file globbing syntax for its wildcards. Also, GLOB is case sensitive, unlike LIKE. Both GLOB and LIKE may be preceded by the NOT keyword to invert the sense of the test.

A column name can be any of the names defined in the CREATE TABLE statement or one of the following special identifiers: "ROWID", "OID", or "_ROWID_". These special identifiers all describe the unique random integer key (the "row key") associated with every row of every table. The special identifiers only refer to the row key if the CREATE TABLE statement does not define a real column with the same name. Row keys act like read-only columns. A row key can be used anywhere a regular column can be used, except that you cannot change the value of a row key in an UPDATE or INSERT statement. "SELECT * ..." does not return the row key.

SELECT statements can appear in expressions as either the right-hand operand of the IN operator or as a scalar quantity. In both cases, the SELECT should have only a single column in its result. Compound SELECTs (connected with keywords like UNION or EXCEPT) are allowed. Any ORDER BY clause on the select is ignored. A SELECT in an expression is evaluated once before any other processing is performed, so none of the expressions within the select itself can refer to quantities in the containing expression.

When a SELECT is the right operand of the IN operator, the IN operator returns TRUE if the result of the left operand is any of the values generated by the select. The IN operator may be preceded by the NOT keyword to invert the sense of the test.

When a SELECT appears within an expression but is not the right operand of an IN operator, then the first row of the result of the SELECT becomes the value used in the expression. If the SELECT yields more than one result row, all rows after the first are ignored. If the SELECT yeilds no rows, then the value of the SELECT is NULL.

The expression syntax currently supports the following functions:

count    min       max       sum
avg      length    substr

The functions count, sum, and avg and the functions min and max used with only one argument are all aggregate functions. This means that they are computed across all rows of the result. The functions min and max with two or more arguments and the functions length and substr are non-aggregates. Non-aggregate functions are computed separately for each row of the result.

The "count(*)" syntax is supported but "count(distinct COLUMN-NAME)" is not.

} Section INSERT insert Syntax {sql-statement} { INSERT INTO [( )] VALUES ( ) | INSERT INTO [( )] } puts {

The INSERT statement comes in two basic forms. The first form (with the "VALUES" keyword) creates a single new row in an existing table. If no column-list is specified then the number of values must be the same as the number of columns in the table. If a column-list is specified, then the number of values must match the number of specified columns. Columns of the table that do not appear in the column list are fill with the default value, or with NULL if not default value is specified.

The second form of the INSERT statement takes it data from a SELECT statement. The number of columns in the result of the SELECT must exactly match the number of columns in the table if no column list is specified, or it must match the number of columns name in the column list. A new entry is made in the table for every row of the SELECT result. The SELECT may be simple or compound. If the SELECT statement has an ORDER BY clause, the ORDER BY is ignored.

} Section SELECT select Syntax {sql-statement} { SELECT FROM [WHERE ] [GROUP BY ] [HAVING ] [