# # Run this Tcl script to generate the sqlite.html file. # set rcsid {$Id: lang.tcl,v 1.31 2002/04/06 14:10:48 drh Exp $} puts { Query Language Understood By SQLite

SQL As Understood By SQLite

} puts "

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

" 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 syntax:

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 []] [ON CONFLICT ] } 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.

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 one is not already in effect. Automatically stared transactions are committed at the conclusion of the command.

Transactions can be started manually using the BEGIN command. Such transactions usually persist until the next COMMIT or ROLLBACK command. But a transaction will also ROLLBACK if the database is closed or if an error occurs and the ROLLBACK conflict resolution algorithm is specified. See the documention on the ON CONFLICT clause for additional information about the ROLLBACK conflict resolution algorithm.

The optional ON CONFLICT clause at the end of a BEGIN statement can be used to changed the default conflict resolution algorithm. The normal default is ABORT. If an alternative is specified by the ON CONFLICT clause of a BEGIN, then that alternative is used as the default for all commands within the transaction. The default algorithm is overridden by ON CONFLICT clauses on individual constraints within the CREATE TABLE or CREATE INDEX statements and by the OR clauses on COPY, INSERT, and UPDATE commands.

} Section COPY copy Syntax {sql-statement} { COPY [ OR ] FROM [ USING DELIMITERS ] } 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. The optional USING DELIMITERS clause can specify a delimiter other than tab.

If a column consists of the character "\N", that column is filled with the value NULL.

The optional conflict-clause allows the specification of an alternative constraint conflict resolution algorithm to use for this one command. See the section titled ON CONFLICT for additional information.

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 [UNIQUE] INDEX ON ( [, ]* ) [ ON CONFLICT ] } {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.

If the UNIQUE keyword appears between CREATE and INDEX then duplicate index entries are not allowed. Any attempt to insert a duplicate entry will result in a rollback and an error message.

The optional conflict-clause allows the specification of al alternative default constraint conflict resolution algorithm for this index. This only makes sense if the UNIQUE keyword is used since otherwise there are not constraints on the index. The default algorithm is ABORT. If a COPY, INSERT, or UPDATE statement specifies a particular conflict resolution algorithm, that algorithm is used in place of the default algorithm specified here. See the section titled ON CONFLICT for additional information.

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 [TEMP | TEMPORARY] TABLE ( [, ]* [, ]* ) } {sql-command} { CREATE [TEMP | TEMPORARY] TABLE AS } {column-def} { [] []* } {type} { | ( ) | ( , ) } {column-constraint} { NOT NULL [ ] | PRIMARY KEY [] [ ] | UNIQUE [ ] | CHECK ( ) [ ] | DEFAULT } {constraint} { PRIMARY KEY ( [, ]* ) [ ]| UNIQUE ( [, ]* ) [ ] | CHECK ( ) [ ] } {conflict-clause} { ON CONFLICT } 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 (usually) ignored and may be omitted. All information is stored as null-terminated strings. The UNIQUE constraint causes an index to be created on the specified columns. This index must contain unique keys. The DEFAULT constraint specifies a default value to use when doing an INSERT.

Specifying a PRIMARY KEY normally just creates a UNIQUE index on the primary key. However, if primary key is on a single column that has datatype INTEGER, then that column is used internally as the actual key of the B-Tree for the table. This means that the column may only hold unique integer values. (Except for this one case, SQLite ignores the datatype specification of columns and allows any kind of data to be put in a column regardless of its declared datatype.) If a table does not have an INTEGER PRIMARY KEY column, then the B-Tree key will be a automatically generated integer. The B-Tree key for a row can always be accessed using one of the special names "ROWID", "OID", or "_ROWID_". This is true regardless of whether or not there is an INTEGER PRIMARY KEY.

If the "TEMP" or "TEMPORARY" keyword occurs in between "CREATE" and "TABLE" then the table that is created is only visible to the process that opened the database and is automatically deleted when the database is closed. Any indices created on a temporary table are also temporary. Temporary tables and indices are stored in a separate file distinct from the main database file.

The optional conflict-clause following each constraint allows the specification of an alternative default constraint conflict resolution algorithm for that constraint. The default is abort ABORT. Different constraints within the same table may have different default conflict resolution algorithms. If an COPY, INSERT, or UPDATE command specifies a different conflict resolution algorithm, then that algorithm is used in place of the default algorithm specified in the CREATE TABLE statement. See the section titled ON CONFLICT for additional information.

CHECK constraints are ignored in the current implementation. Support for CHECK constraints may be added in the future. As of version 2.3.0, NOT NULL, PRIMARY KEY, and UNIQUE constraints all work.

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 about 1 megabytes. (This limit can be increased to 16MB by changing a single #define in the source code and recompiling.)

The CREATE TABLE AS form defines the table to be the result set of a query. The names of the table columns are the names of the columns in the result.

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. If the original command was a CREATE TABLE AS then then an equivalent CREATE TABLE statement is synthesized and store in sqlite_master in place of the original command.

} Section {CREATE VIEW} {createview} Syntax {sql-command} { CREATE VIEW AS } puts {

The CREATE VIEW command assigns a name to a pre-packaged SELECT statement. Once the view is created, it can be used in the FROM clause of another SELECT in place of a table name.

You cannot COPY, INSERT or UPDATE a view. Views are read-only.

} 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 {DROP VIEW} dropview Syntax {sql-command} { DROP VIEW } puts {

The DROP VIEW statement consists of the keywords "DROP TABLE" followed by the name of the view. The view named is removed from the database. But no actual data is modified.

} 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. Most other sections 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

Supported unary operaters are these:

-    +    !    ~

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.

Both simple and aggregate functions are supported. A simple function can be used in any expression. Simple functions return a result immediately based on their inputs. Aggregate functions may only be used in a SELECT statement. Aggregate functions compute their result across all rows of the result set.

The following simple functions are currently supported:

abs(X) Return the absolute value of argument X.
coalesce(X,Y,...) Return a copy of the first non-NULL argument. If all arguments are NULL then NULL is returned.
last_insert_rowid() Return the ROWID of the last row insert from this connection to the database. This is the same value that would be returned from the sqlite_last_insert_rowid() API function.
length(X) Return the string length of X in characters. If SQLite is configured to support UTF-8, then the number of UTF-8 characters is returned, not the number of bytes.
lower(X) Return a copy of string X will all characters converted to lower case. The C library tolower() routine is used for the conversion, which means that this function might not work correctly on UTF-8 characters.
max(X,Y,...) Return the argument with the maximum value. Arguments may be strings in addition to numbers. The maximum value is determined by the usual sort order. Note that max() is a simple function when it has 2 or more arguments but converts to an aggregate function if given only a single argument.
min(X,Y,...) Return the argument with the minimum value. Arguments may be strings in addition to numbers. The mminimum value is determined by the usual sort order. Note that min() is a simple function when it has 2 or more arguments but converts to an aggregate function if given only a single argument.
random(*) Return a random integer between -2147483648 and +2147483647.
round(X)
round(X,Y)
Round off the number X to Y digits to the right of the decimal point. If the Y argument is omitted, 0 is assumed.
substr(X,Y,Z) Return a substring of input string X that begins with the Y-th character and which is Z characters long. The left-most character of X is number 1. If Y is negative the the first character of the substring is found by counting from the right rather than the left. If SQLite is configured to support UTF-8, then characters indices refer to actual UTF-8 characters, not bytes.
upper(X) Return a copy of input string X converted to all upper-case letters. The implementation of this function uses the C library routine toupper() which means it may not work correctly on UTF-8 strings.

The following aggregate functions are supported:

avg(X) Return the average value of all X within a group.
count(X)
count(*)
The first form return a count of the number of times that X is not NULL in a group. The second form (with no argument) returns the total number of rows in the group.
max(X) Return the maximum value of all values in the group. The usual sort order is used to determine the maximum.
min(X) Return the minimum value of all values in the group. The usual sort order is used to determine the minimum.
sum(X) Return the numeric sum of all values in the group.
} Section INSERT insert Syntax {sql-statement} { INSERT [OR ] INTO [()] VALUES() | INSERT [OR ] 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.

The optional conflict-clause allows the specification of an alternative constraint conflict resolution algorithm to use during this one command. See the section titled ON CONFLICT for additional information. For compatibility with MySQL, the parser allows the use of the single keyword "REPLACE" as an alias for "INSERT OR REPLACE".

} Section {ON CONFLICT clause} conflict Syntax {conflict-clause} { ON CONFLICT } {conflict-algorithm} { ROLLBACK | ABORT | FAIL | IGNORE | REPLACE } puts {

The ON CONFLICT clause is not a separate SQL command. It is a non-standard clause that can appear in many other SQL commands. It is given its own section in this document because it is not part of standard SQL and therefore might not be familiar.

The syntax for the ON CONFLICT clause is as shown above for the CREATE TABLE, CREATE INDEX, and BEGIN TRANSACTION commands. For the COPY, INSERT, and UPDATE commands, the keywords "ON CONFLICT" are replaced by "OR", to make the syntax seem more natural. But the meaning of the clause is the same either way.

The ON CONFLICT clause specifies an algorithm used to resolve constraint conflicts. There are five choices: ROLLBACK, ABORT, FAIL, IGNORE, and REPLACE. The default algorithm is ABORT. This is what they mean:

ROLLBACK

When a constraint violation occurs, an immediate ROLLBACK occurs, thus ending the current transaction, and the command aborts with a return code of SQLITE_CONSTRAINT. If no transaction is active (other than the implied transaction that is created on every command) then this algorithm works the same as ABORT.

ABORT

When a constraint violation occurs, the command backs out any prior changes it might have made and aborts with a return code of SQLITE_CONSTRAINT. But no ROLLBACK is executed so changes from prior commands within the same transaction are preserved. This is the default behavior.

FAIL

When a constraint violation occurs, the command aborts with a return code SQLITE_CONSTRAINT. But any changes to the database that the command made prior to encountering the constraint violation are preserved and are not backed out. For example, if an UPDATE statement encountered a constraint violation on the 100th row that it attempts to update, then the first 99 row changes are preserved but changes to rows 100 and beyond never occur.

IGNORE

When a constraint violation occurs, the one row that contains the constraint violation is not inserted or changed. But the command continues executing normally. Other rows before and after the row that contained the constraint violation continue to be inserted or updated normally. No error is returned.

REPLACE

When a UNIQUE constraint violation occurs, the pre-existing row that is causing the constraint violation is removed prior to inserting or updating the current row. Thus the insert or update always occurs. The command continues executing normally. No error is returned.

If a NOT NULL constraint violation occurs, the NULL value is replaced by the default value for that column. If the column has no default value, then the ABORT algorithm is used.

The conflict resolution algorithm can be specified in three places, in order from lowest to highest precedence:

  1. On a BEGIN TRANSACTION command.

  2. On individual constraints within a CREATE TABLE or CREATE INDEX statement.

  3. In the OR clause of a COPY, INSERT, or UPDATE command.

The algorithm specified in the OR clause of a COPY, INSERT, or UPDATE overrides any algorithm specified by a CREATE TABLE or CREATE INDEX. The algorithm specified within a CREATE TABLE or CREATE INDEX will, in turn, override the algorithm specified by a BEGIN TRANSACTION command. If no algorithm is specified anywhere, the ABORT algorithm is used.

} #

For additional information, see # conflict.html.

Section PRAGMA pragma Syntax {sql-statement} { PRAGMA = | PRAGMA () } puts {

The PRAGMA command is used to modify the operation of the SQLite library. The pragma command is experimental and specific pragma statements may removed or added in future releases of SQLite. Use this command with caution.

The current implementation supports the following pragmas:

  • PRAGMA cache_size;
    PRAGMA cache_size =
    Number-of-pages;

    Query or change the maximum number of database disk pages that SQLite will hold in memory at once. Each page uses about 1.5K of memory. The default cache size is 2000. If you are doing UPDATEs or DELETEs that change many rows of a database and you do not mind if SQLite uses more memory, you can increase the cache size for a possible speed improvement.

    When you change the cache size using the cache_size pragma, the change only endures for the current session. The cache size reverts to the default value when the database is closed and reopened. Use the default_cache_size pragma to check the cache size permanently

  • PRAGMA count_changes = ON;
    PRAGMA count_changes = OFF;

    When on, the COUNT_CHANGES pragma causes the callback function to be invoked once for each DELETE, INSERT, or UPDATE operation. The argument is the number of rows that were changed.

  • PRAGMA default_cache_size;
    PRAGMA default_cache_size =
    Number-of-pages;

    Query or change the maximum number of database disk pages that SQLite will hold in memory at once. Each page uses about 1.5K of memory. This pragma works like the cache_size pragma with the addition feature that it changes the cache size persistently. With this pragma, you can set the cache size once and that setting is retained and reused everytime you reopen the database.

  • PRAGMA default_synchronous;
    PRAGMA default_synchronous = ON;
    PRAGMA default_synchronous = OFF;

    Query or change the setting of the "synchronous" flag in the database. When synchronous is on (the default), the SQLite database engine will pause at critical moments to make sure that data has actually be written to the disk surface. (In other words, it invokes the equivalent of the fsync() system call.) In synchronous mode, an SQLite database should be fully recoverable even if the operating system crashes or power is interrupted unexpectedly. The penalty for this assurance is that some database operations take longer because the engine has to wait on the (relatively slow) disk drive. The alternative is to turn synchronous off. With synchronous off, SQLite continues processing as soon as it has handed data off to the operating system. If the application running SQLite crashes, the data will be safe, but the database could (in theory) become corrupted if the operating system crashes or the computer suddenly loses power. On the other hand, some operations are as much as 50 or more times faster with synchronous off.

    This pragma changes the synchronous mode persistently. Once changed, the mode stays as set even if the database is closed and reopened. The synchronous pragma does the same thing but only applies the setting to the current session.

  • PRAGMA empty_result_callbacks = ON;
    PRAGMA empty_result_callbacks = OFF;

    When on, the EMPTY_RESULT_CALLBACKS pragma causes the callback function to be invoked once for each query that has an empty result set. The third "argv" parameter to the callback is set to NULL because there is no data to report. But the second "argc" and fourth "columnNames" parameters are valid and can be used to determine the number and names of the columns that would have been in the result set had the set not been empty.

  • PRAGMA full_column_names = ON;
    PRAGMA full_column_names = OFF;

    The column names reported in an SQLite callback are normally just the name of the column itself, except for joins when "TABLE.COLUMN" is used. But when full_column_names is turned on, column names are always reported as "TABLE.COLUMN" even for simple queries.

  • PRAGMA index_info(index-name);

    For each column that the named index references, invoke the callback function once with information about that column, including the column name, and the column number.

  • PRAGMA index_list(table-name);

    For each index on the named table, invoke the callback function once with information about that index. Arguments include the index name and a flag to indicate whether or not the index must be unique.

  • PRAGMA parser_trace = ON;
    PRAGMA parser_trace = OFF;

    Turn tracing of the SQL parser inside of the SQLite library on and off. This is used for debugging. This only works if the library is compiled without the NDEBUG macro.

  • PRAGMA integrity_check;

    The command does an integrity check of the entire database. It looks for out-of-order records, missing pages, and malformed records. If any problems are found, then a single string is returned which is a description of all problems. If everything is in order, "ok" is returned.

  • PRAGMA synchronous;
    PRAGMA synchronous = ON;
    PRAGMA synchronous = OFF;

    Query or change the setting of the "synchronous" flag in the database for the duration of the current database connect. The synchronous flag reverts to its default value when the database is closed and reopened. For additional information on the synchronous flag, see the description of the default_synchronous pragma.

  • PRAGMA table_info(table-name);

    For each column in the named table, invoke the callback function once with information about that column, including the column name, data type, whether or not the column can be NULL, and the default value for the column.

  • PRAGMA vdbe_trace = ON;
    PRAGMA vdbe_trace = OFF;

    Turn tracing of the virtual database engine inside of the SQLite library on and off. This is used for debugging.

No error message is generated if an unknown pragma is issued. Unknown pragmas are ignored.

} Section REPLACE replace Syntax {sql-statement} { REPLACE INTO [( )] VALUES ( ) | REPLACE INTO [( )] } puts {

The REPLACE command is an alias for the "INSERT OR REPLACE" variant of the INSERT command. This alias is provided for compatibility with MySQL. See the INSERT command documentation for additional information.

} Section SELECT select Syntax {sql-statement} { SELECT [FROM ] [WHERE ] [GROUP BY ] [HAVING ] [ ) [AS ] } {sort-expr-list} { [] [, []]* } {sort-order} { ASC | DESC } {compound_op} { UNION | UNION ALL | INTERSECT | EXCEPT } puts {

The SELECT statement is used to query the database. The result of a SELECT is zero or more rows of data where each row has a fixed number of columns. The number of columns in the result is specified by the expression list in between the SELECT and FROM keywords. Any arbitrary expression can be used as a result. If a result expression is } puts "[Operator *] then all columns of all tables are substituted" puts {for that one expression.

The query is executed again one or more tables specified after the FROM keyword. If more than one table is specified, then the query is against the (inner) join of the various tables. A sub-query in parentheses may be substituted for any table name in the FROM clause. The entire FROM clause may be omitted, in which case the result is a single row consisting of the values of the expression list.

The WHERE clause can be used to limit the number of rows over which the query operates. In the current implementation, indices will only be used to optimize the query if WHERE expression contains equality comparisons connected by the AND operator.

The GROUP BY clauses causes one or more rows of the result to be combined into a single row of output. This is especially useful when the result contains aggregate functions. The expressions in the GROUP BY clause do not have to be expressions that appear in the result. The HAVING clause is similar to WHERE except that HAVING applies after grouping has occurred. The HAVING expression may refer to values, even aggregate functions, that are not in the result.

The ORDER BY clause causes the output rows to be sorted. The argument to ORDER BY is a list of expressions that are used as the key for the sort. The expressions do not have to be part of the result for a simple SELECT, but in a compound SELECT each sort expression must exactly match one of the result columns. Each sort expression may be optionally followed by ASC or DESC to specify the sort order.

The LIMIT clause places an upper bound on the number of rows returned in the result. A LIMIT of 0 indicates no upper bound. The optional OFFSET following LIMIT specifies how many rows to skip at the beginning of the result set.

A compound SELECT is formed from two or more simple SELECTs connected by one of the operators UNION, UNION ALL, INTERSECT, or EXCEPT. In a compound SELECT, all the constituent SELECTs must specify the same number of result columns. There may be only a single ORDER BY clause at the end of the compound SELECT. The UNION and UNION ALL operators combine the results of the SELECTs to the right and left into a single big table. The difference is that in UNION all result rows are distinct where in UNION ALL there may be duplicates. The INTERSECT operator takes the intersection of the results of the left and right SELECTs. EXCEPT takes the result of left SELECT after removing the results of the right SELECT. When three are more SELECTs are connected into a compound, they group from left to right.

} Section UPDATE update Syntax {sql-statement} { UPDATE [ OR ] SET [, ] [WHERE ] } {assignment} { = } puts {

The UPDATE statement is used to change the value of columns in selected rows of a table. Each assignment in an UPDATE specifies a column name to the left of the equals sign and an arbitrary expression to the right. The expressions may use the values of other columns. All expressions are evaluated before any assignments are made. A WHERE clause can be used to restrict which rows are updated.

The optional conflict-clause allows the specification of an alternative constraint conflict resolution algorithm to use during this one command. See the section titled ON CONFLICT for additional information.

} Section VACUUM vacuum Syntax {sql-statement} { VACUUM [] } puts {

The VACUUM command is an SQLite extension modelled after a similar command found in PostgreSQL. If VACUUM is invoked with the name of a table or index then it is suppose to clean up the named table or index. In version 1.0 of SQLite, the VACUUM command would invoke gdbm_reorganize() to clean up the backend database file. Beginning with version 2.0 of SQLite, GDBM is no longer used for the database backend and VACUUM has become a no-op.

} puts {


Back to the SQLite Home Page

}