SQL As Understood By SQLite

SQLite 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 precisely what parts of the SQL language SQLite does and does not support. A list of [SQL keywords] is also provided. The SQL language syntax is described by [syntax diagrams].

The following syntax documentation topics are available:

    set i 0 set lang_section_list { {{CREATE TABLE} createtable} {{CREATE VIRTUAL TABLE} createvtab} {{CREATE INDEX} createindex} {VACUUM vacuum} {{DROP TABLE} droptable} {{DROP INDEX} dropindex} {INSERT insert} {REPLACE replace} {DELETE delete} {UPDATE update} {SELECT select} {comment comment} {EXPLAIN explain} {expression expr} {{BEGIN TRANSACTION} transaction} {{COMMIT TRANSACTION} transaction COMMIT} {{END TRANSACTION} transaction COMMIT} {{ROLLBACK TRANSACTION} transaction ROLLBACK} {SAVEPOINT savepoint} {{RELEASE SAVEPOINT} savepoint SAVEPOINT} {PRAGMA pragma.html} {{ON CONFLICT clause} conflict} {{CREATE VIEW} createview} {{DROP VIEW} dropview} {{CREATE TRIGGER} createtrigger} {{DROP TRIGGER} droptrigger} {{ATTACH DATABASE} attach} {{DETACH DATABASE} detach} {REINDEX reindex} {{ALTER TABLE} altertable} {{ANALYZE} analyze} {{INDEXED BY} indexedby} {{aggregate functions} aggfunc aggfunc} {{core functions} corefunc corefunc} {{date and time functions} datefunc datefunc} {keywords keywords {SQL keywords}} } set lang_section_break [expr {([llength $lang_section_list]+2)/3}] foreach {section} [lsort -index 0 -dictionary $lang_section_list] { foreach {s_title s_tag s_kw} $section {} if {$s_kw == ""} { set s_kw $s_title } if {$s_tag=="pragma.html"} { set url $s_tag } else { set url lang_$s_tag.html } hd_resolve "
  • \[$s_kw|$s_title\]
  • " incr i if {$i==$lang_section_break || $i==2*$lang_section_break} { hd_puts "
    " } }

^The routines [sqlite3_prepare_v2()], [sqlite3_prepare()], [sqlite3_prepare16()], [sqlite3_prepare16_v2()], [sqlite3_exec()], and [sqlite3_get_table()] accept an SQL statement list (sql-stmt-list) which is a semicolon-separated list of statements.

BubbleDiagram sql-stmt-list

Each SQL statement in the statement list is an instance of the following:

BubbleDiagram sql-stmt proc Operator {name} { return "$name" } proc Nonterminal {name} { return "$name" } proc Keyword {name} { return "$name" } proc Example {text} { hd_puts "
$text
" } proc Section {name label keywords} { global DOC hd_close_main hd_open_main lang_$label.html hd_header "SQLite Query Language: $name" $DOC/pages/lang.in eval hd_keywords $keywords if {[lsearch $keywords $name] == -1 && [lsearch $keywords *$name] == -1} { eval hd_keywords { $name } } hd_puts {

SQL As Understood By SQLite

} hd_puts {

[Top]

} hd_puts "

$name

" } ############################################################################### Section {ALTER TABLE} altertable {{ALTER TABLE} {*ALTER}} BubbleDiagram alter-table-stmt 1

SQLite supports a limited subset of ALTER TABLE. The ALTER TABLE command in SQLite allows the user to rename a table or to add a new column to an existing table. It is not possible to rename a column, remove a column, or add or remove constraints from a table.

^(The RENAME TO syntax is used to rename the table identified by [database-name.]table-name to new-table-name.)^ This command cannot be used to move a table between attached databases, only to rename a table within the same database.

^If the table being renamed has triggers or indices, then these remain attached to the table after it has been renamed. ^However, if there are any view definitions, or statements executed by triggers that refer to the table being renamed, these are not automatically modified to use the new table name. If this is required, the triggers or view definitions must be dropped and recreated to use the new table name by hand.

^If [foreign key constraints] are [foreign_keys pragma | enabled] when a table is renamed, then any [foreign-key-clause | REFERENCES clauses] in any table (either the table being renamed or some other table) that refer to the table being renamed are modified to refer to the renamed table by its new name.

^The ADD COLUMN syntax is used to add a new column to an existing table. ^The new column is always appended to the end of the list of existing columns. The [column-def] rule defines the characteristics of the new column. ^(The new column may take any of the forms permissible in a [CREATE TABLE] statement, with the following restrictions:)^

^Note also that when adding a [CHECK constraint], the CHECK constraint is not tested against preexisting rows of the table. ^This can result in a table that contains data that is in violation of the CHECK constraint. Future versions of SQLite might change to validate CHECK constraints as they are added.

The execution time of the ALTER TABLE command is independent of the amount of data in the table. The ALTER TABLE command runs as quickly on a table with 10 million rows as it does on a table with 1 row.

After ADD COLUMN has been run on a database, that database will not be readable by SQLite version 3.1.3 and earlier.

############################################################################## Section {ANALYZE} analyze ANALYZE BubbleDiagram analyze-stmt 1

^The ANALYZE command gathers statistics about tables and indices and stores the collected information in a special tables in the database where the query optimizer can use them to help make better query planning choices. ^If no arguments are given, all attached databases are analyzed. ^If a database name is given as the argument, then all tables and indices in that one database are analyzed. ^If the argument is a table name, then only that table and the indices associated with that table are analyzed. ^If the argument is an index name, then only that one index is analyzed.

^The default implementation stores all statistics in a single table named sqlite_stat1. ^If SQLite is compiled with the [SQLITE_ENABLE_STAT2] option, then additional histogram data is collected and stored in sqlite_stat2. Future enhancements may create additional tables with the same name pattern except with the "1" or "2" changed to a different digit.

^The [DROP TABLE] and [ALTER TABLE] commands do not work on the sqlite_stat1 or sqlite_stat2 tables, but all the content of those tables can be queried using [SELECT] and can be deleted, augmented, or modified using the [DELETE], [INSERT], and [UPDATE] commands. Appropriate care should be used when changing the content of the statistics tables as invalid content can cause SQLite to select inefficient query plans. Generally speaking, one should not modify the content of the statistics tables by any mechanism other than invoking the ANALYZE command.

^Statistics gathered by ANALYZE are not automatically updated as the content of the database changes. If the content of the database changes significantly, or if the database schema changes, then one should consider rerunning the ANALYZE command in order to update the statistics.

The query planner might not notice manual changes to the sqlite_stat1 and/or sqlite3_stat2 tables. ^An application can force the query planner to reread the statistics tables by running ANALYZE sqlite_master.

############################################################################## Section {ATTACH DATABASE} attach *ATTACH BubbleDiagram attach-stmt 1

^The ATTACH DATABASE statement adds another database file to the current [database connection]. ^The filename for the database to be attached is the value of the expression that occurs before the AS keyword. ^The filename of the database follows the same semantics as the filename argument to [sqlite3_open()] and [sqlite3_open_v2()]; the special name "[:memory:]" results in an in-memory database and an empty string results in a new temporary database. ^The filename argument can be a [URI filename] if URI filename processing is enable on the database connection. The name that occurs after the AS keyword is the name of the database used internally by SQLite. ^The database-names 'main' and 'temp' refer to the main database and the database used for temporary tables. ^The main and temp databases cannot be attached or detached.

^(Tables in an attached database can be referred to using the syntax database-name.table-name.)^ ^If the name of the table is unique across all attached databases and the main and temp databases, then the database-name prefix is not required. ^If two or more tables in different databases have the same name and the database-name prefix is not used on a table reference, then the table chosen is the one in the database that was least recently attached.

^Transactions involving multiple attached databases are atomic, assuming that the main database is not "[:memory:]" and the [journal_mode] is not [WAL]. ^(If the main database is ":memory:" or if the journal_mode is WAL, then transactions continue to be atomic within each individual database file. But if the host computer crashes in the middle of a [COMMIT] where two or more database files are updated, some of those files might get the changes where others might not.)^

^There is a limit, set using [sqlite3_limit()] and [SQLITE_LIMIT_ATTACHED], to the number of databases that can be simultaneously attached to a single database connection.

############################################################################### Section {BEGIN TRANSACTION} transaction {*BEGIN COMMIT ROLLBACK} BubbleDiagram begin-stmt BubbleDiagram commit-stmt BubbleDiagram rollback-stmt

^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 start a transaction if one is not already in effect. ^Automatically started transactions are committed when the last query finishes.

^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 documentation on the [ON CONFLICT] clause for additional information about the ROLLBACK conflict resolution algorithm.

^END TRANSACTION is an alias for COMMIT.

^(Transactions created using BEGIN...COMMIT do not nest.)^ ^For nested transactions, use the [SAVEPOINT] and [RELEASE] commands. The "TO SAVEPOINT name" clause of the ROLLBACK command shown in the syntax diagram above is only applicable to [SAVEPOINT] transactions. ^An attempt to invoke the BEGIN command within a transaction will fail with an error, regardless of whether the transaction was started by [SAVEPOINT] or a prior BEGIN. ^The COMMIT command and the ROLLBACK command without the TO clause work the same on [SAVEPOINT] transactions as they do with transactions started by BEGIN.

^Transactions can be deferred, immediate, or exclusive. ^The default transaction behavior is deferred. ^Deferred means that no locks are acquired on the database until the database is first accessed. ^Thus with a deferred transaction, the BEGIN statement itself does nothing to the filesystem. ^Locks are not acquired until the first read or write operation. ^The first read operation against a database creates a [SHARED] lock and the first write operation creates a [RESERVED] lock. ^Because the acquisition of locks is deferred until they are needed, it is possible that another thread or process could create a separate transaction and write to the database after the BEGIN on the current thread has executed. ^If the transaction is immediate, then [RESERVED] locks are acquired on all databases as soon as the BEGIN command is executed, without waiting for the database to be used. ^After a BEGIN IMMEDIATE, no other [database connection] will be able to write to the database or do a BEGIN IMMEDIATE or BEGIN EXCLUSIVE. ^Other processes can continue to read from the database, however. ^An exclusive transaction causes [EXCLUSIVE] locks to be acquired on all databases. ^After a BEGIN EXCLUSIVE, no other [database connection] except for [read_uncommitted] connections will be able to read the database and no other connection without exception will be able to write the database until the transaction is complete.

^(An implicit transaction (a transaction that is started automatically, not a transaction started by BEGIN) is committed automatically when the last active statement finishes. A statement finishes when its prepared statement is [sqlite3_reset() | reset] or [sqlite3_finalize() | finalized]. An open [sqlite3_blob] used for incremental BLOB I/O counts as an unfinished statement. The [sqlite3_blob] finishes when it is [sqlite3_blob_close() | closed].)^

^The explicit COMMIT command runs immediately, even if there are pending [SELECT] statements. ^However, if there are pending write operations, the COMMIT command will fail with a error code [SQLITE_BUSY].

^An attempt to execute COMMIT might also result in an [SQLITE_BUSY] return code if an another thread or process has a [shared lock] on the database that prevented the database from being updated. ^When COMMIT fails in this way, the transaction remains active and the COMMIT can be retried later after the reader has had a chance to clear.

^The ROLLBACK will fail with an error code [SQLITE_BUSY] if there are any pending queries. ^Both read-only and read/write queries will cause a ROLLBACK to fail. A ROLLBACK must fail if there are pending read operations (unlike COMMIT which can succeed) because bad things will happen if the in-memory image of the database is changed out from under an active query.

If [PRAGMA journal_mode] is set to OFF (thus disabling the rollback journal file) then the behavior of the ROLLBACK command is undefined.

Response To Errors Within A Transaction

^(If certain kinds of errors occur within a transaction, the transaction may or may not be rolled back automatically. The errors that cause the behavior include:

)^

^For all of these errors, SQLite attempts to undo just the one statement it was working on and leave changes from prior statements within the same transaction intact and continue with the transaction. ^However, depending on the statement being evaluated and the point at which the error occurs, it might be necessary for SQLite to rollback and cancel the entire transaction. ^An application can tell which course of action SQLite took by using the [sqlite3_get_autocommit()] C-language interface.

It is recommended that applications respond to the errors listed above by explicitly issuing a ROLLBACK command. ^If the transaction has already been rolled back automatically by the error response, then the ROLLBACK command will fail with an error, but no harm is caused by this.

Future versions of SQLite may extend the list of errors which might cause automatic transaction rollback. Future versions of SQLite might change the error response. In particular, we may choose to simplify the interface in future versions of SQLite by causing the errors above to force an unconditional rollback.

############################################################################### Section {SAVEPOINT} savepoint {SAVEPOINT RELEASE} BubbleDiagram savepoint-stmt BubbleDiagram release-stmt BubbleDiagram rollback-stmt

^SAVEPOINTs are a method of creating transactions, similar to [BEGIN] and [COMMIT], except that the SAVEPOINT and RELEASE commands are named and may be nested.

^The SAVEPOINT command starts a new transaction with a name. ^The transaction names need not be unique. ^(A SAVEPOINT can be started either within or outside of a [BEGIN]...[COMMIT].)^ ^(When a SAVEPOINT is the outer-most savepoint and it is not within a [BEGIN]...[COMMIT] then the behavior is the same as BEGIN DEFERRED TRANSACTION.)^

^The ROLLBACK TO command reverts the state of the database back to what it was just after the corresponding SAVEPOINT. ^Note that unlike that plain [ROLLBACK] command (without the TO keyword) the ROLLBACK TO command does not cancel the transaction. ^Instead of cancelling the transaction, the ROLLBACK TO command restarts the transaction again at the beginning. ^All intervening SAVEPOINTs are canceled, however.

^The RELEASE command is like a [COMMIT] for a SAVEPOINT. ^The RELEASE command causes all savepoints back to and including the most recent savepoint with a matching name to be removed from the transaction stack. ^The RELEASE of an inner transaction does not cause any changes to be written to the database file; it merely removes savepoints from the transaction stack such that it is no longer possible to ROLLBACK TO those savepoints. ^If a RELEASE command releases the outermost savepoint, so that the transaction stack becomes empty, then RELEASE is the same as [COMMIT]. ^The [COMMIT] command may be used to release all savepoints and commit the transaction even if the transaction was originally started by a SAVEPOINT command instead of a [BEGIN] command.

^If the savepoint-name in a RELEASE command does not match any savepoint currently in the transaction stack, then no savepoints are released, the database is unchanged, and the RELEASE command returns an error.

^Note that an inner transaction might commit (using the RELEASE command) but then later have its work undone by a ROLLBACK in an outer transaction. ^A power failure or program crash or OS crash will cause the outer-most transaction to rollback, undoing all changes that have occurred within that outer transaction, even changes that have supposedly been "committed" by the RELEASE command. ^Content is not actually committed on the disk until the outermost transaction commits.

There are several ways of thinking about the RELEASE command:

Transaction Nesting Rules

^The last transaction started will be the first transaction committed or rolled back.

^The [BEGIN] command only works if the transaction stack is empty, or in other words if there are no pending transactions. ^If the transaction stack is not empty when the [BEGIN] command is invoked, then the command fails with an error.

^The [COMMIT] command commits all outstanding transactions and leaves the transaction stack empty.

^The RELEASE command starts with the most recent addition to the transaction stack and releases savepoints backwards in time until it releases a savepoint with a matching savepoint-name. ^Prior savepoints, even savepoints with matching savepoint-names, are unchanged. ^If the RELEASE command causes the transaction stack to become empty (if the RELEASE command releases the outermost transaction from the stack) then the transaction commits.

^The [ROLLBACK] command without a TO clause rolls backs all transactions and leaves the transaction stack empty.

^The ROLLBACK command with a TO clause rolls back transactions going backwards in time back to the most recent SAVEPOINT with a matching name. ^The SAVEPOINT with the matching name remains on the transaction stack, but all database changes that occurred after that SAVEPOINT was created are rolled back. ^If the savepoint-name in a ROLLBACK TO command does not match any SAVEPOINT on the stack, then the ROLLBACK command fails with an error and leaves the state of the database unchanged.

############################################################################### Section comment comment {comment *comments} BubbleDiagram comment-syntax

^Comments are not SQL commands, but can occur within the text of SQL queries passed to [sqlite3_prepare_v2()] and related interfaces. ^Comments are treated as whitespace by the parser. ^Comments can begin anywhere whitespace can be found, including inside expressions that span multiple lines.

^SQL comments begin with two consecutive "-" characters (ASCII 0x2d) and extend up to and including the next newline character (ASCII 0x0a) or until the end of input, whichever comes first.

^C-style comments begin with "/*" and extend up to and including the next "*/" character pair or until the end of input, whichever comes first. ^C-style comments can span multiple lines.

^Comments can appear anywhere whitespace can occur, including inside expressions and in the middle of other SQL statements. ^Comments do not nest.

############################################################################## Section {CREATE INDEX} createindex {{CREATE INDEX}} BubbleDiagram create-index-stmt 1 BubbleDiagram indexed-column

^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. ^The sort order may or may not be ignored depending on the database file format. ^The "legacy" file format ignores index sort order. ^The descending index file format takes index sort order into account. ^(Only copies of SQLite newer than [version 3.3.0] (released on 2006-01-10) are able to understand the newer descending index file format and so for compatibility with older versions of SQLite, the legacy file format is generated by default.)^ ^Use the [legacy_file_format] pragma to modify this behavior and generate databases that use the newer file format. Future versions of SQLite may begin to generate the newer file format by default.

^The COLLATE clause optionally following each column name defines a collating sequence used for text entries in that column. ^The default collating sequence is the collating sequence defined for that column in the [CREATE TABLE] statement. ^Or if no collating sequence is otherwise defined, the built-in BINARY collating sequence is used.

There are no arbitrary limits on the number of indices that can be attached to a single table. ^(The number of columns in an index is limited to the value set by [sqlite3_limit]([SQLITE_LIMIT_COLUMN],...).)^

^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 an error. ^For the purposes of unique indices, all NULL values are considered to different from all other NULL values and are thus unique. This is one of the two possible interpretations of the SQL-92 standard (the language in the standard is ambiguous) and is the interpretation followed by PostgreSQL, MySQL, Firebird, and Oracle. Informix and Microsoft SQL Server follow the other interpretation of the standard.

^If the optional IF NOT EXISTS clause is present and another index with the same name already exists, then this command becomes a no-op.

^Indexes are removed with the [DROP INDEX] command.

############################################################################## Section {CREATE TABLE} {createtable} {{CREATE TABLE}} BubbleDiagram create-table-stmt 1 BubbleDiagram column-def BubbleDiagram type-name BubbleDiagram column-constraint BubbleDiagram table-constraint BubbleDiagram foreign-key-clause

The "CREATE TABLE" command is used to create a new table in an SQLite database. A CREATE TABLE command specifies the following attributes of the new table:

Every CREATE TABLE statement must specify a name for the new table. ^(Table names that begin with "sqlite_" are reserved for internal use. It is an error to attempt to create a table with a name that starts with "sqlite_".)^

^If a <database-name> is specified, it must be either "main", "temp", or the name of an [ATTACH DATABASE|attached database]. ^In this case the new table is created in the named database. ^If the "TEMP" or "TEMPORARY" keyword occurs between the "CREATE" and "TABLE" then the new table is created in the temp database. ^It is an error to specify both a <database-name> and the TEMP or TEMPORARY keyword, unless the <database-name> is "temp". ^If no database name is specified and the TEMP keyword is not present then the table is created in the main database.

^It is usually an error to attempt to create a new table in a database that already contains a table, index or view of the same name. ^However, if the "IF NOT EXISTS" clause is specified as part of the CREATE TABLE statement and a table or view of the same name already exists, the CREATE TABLE command simply has no effect (and no error message is returned). ^An error is still returned if the table cannot be created because of an existing index, even if the "IF NOT EXISTS" clause is specified.

^It is not an error to create a table that has the same name as an existing [CREATE TRIGGER|trigger].

^Tables are removed using the [DROP TABLE] statement.

CREATE TABLE ... AS SELECT Statements

^(A "CREATE TABLE ... AS SELECT" statement creates and populates a database table based on the results of a SELECT statement.)^ ^(The table has the same number of columns as the rows returned by the SELECT statement. The name of each column is the same as the name of the corresponding column in the result set of the SELECT statement.)^ ^(The declared type of each column is determined by the [expression affinity] of the corresponding expression in the result set of the SELECT statement, as follows:

Expression Affinity Column Declared Type
TEXT "TEXT"
NUMERIC "NUM"
INTEGER "INT"
REAL "REAL"
NONE "" (empty string)
)^

^(A table created using CREATE TABLE AS has no PRIMARY KEY and no constraints of any kind. The default value of each column is NULL. The default collation sequence for each column of the new table is BINARY.)^

^Tables created using CREATE TABLE AS are initially populated with the rows of data returned by the SELECT statement. ^Rows are assigned contiguously ascending [rowid] values, starting with 1, in the [order by|order] that they are returned by the SELECT statement. hd_fragment {tablecoldef} {column definition} {column definitions}

Column Definitions

Unless it is a CREATE TABLE ... AS SELECT statement, a CREATE TABLE includes one or more [column-def|column definitions], optionally followed by a list of [table-constraint|table constraints]. Each column definition consists of the name of the column, optionally followed by the declared type of the column, then one or more optional [column-constraint|column constraints]. Included in the definition of "column constraints" for the purposes of the previous statement are the COLLATE and DEFAULT clauses, even though these are not really constraints in the sense that they do not restrict the data that the table may contain. The other constraints - NOT NULL, CHECK, UNIQUE, PRIMARY KEY and FOREIGN KEY constraints - impose restrictions on the tables data, and are are described under [constraints|SQL Data Constraints] below.

^Unlike most SQL databases, SQLite does not restrict the type of data that may be inserted into a column based on the columns declared type. Instead, SQLite uses [dynamic typing]. ^The declared type of a column is used to determine the [affinity] of the column only.

The DEFAULT clause specifies a default value to use for the column if no value is explicitly provided by the user when doing an [INSERT]. ^If there is no explicit DEFAULT clause attached to a column definition, then the default value of the column is NULL. ^(An explicit DEFAULT clause may specify that the default value is NULL, a string constant, a blob constant, a signed-number, or any constant expression enclosed in parentheses. An explicit default value may also be one of the special case-independent keywords CURRENT_TIME, CURRENT_DATE or CURRENT_TIMESTAMP.)^ ^For the purposes of the DEFAULT clause, an expression is considered constant provided that it does not contain any sub-queries or string constants enclosed in double quotes.

^(Each time a row is inserted into the table by an INSERT statement that does not provide explicit values for all table columns the values stored in the new row are determined by their default values)^, as follows:

^The COLLATE clause specifies the name of a [collating sequence] to use as the default collation sequence for the column. ^If no COLLATE clause is specified, the default collation sequence is [BINARY].

^The number of columns in a table is limited by the [SQLITE_MAX_COLUMN] compile-time parameter. ^A single row of a table cannot store more than [SQLITE_MAX_LENGTH] bytes of data. ^Both of these limits can be lowered at runtime using the [sqlite3_limit()] C/C++ interface.

hd_fragment {constraints} {constraints}

SQL Data Constraints

^Each table in SQLite may have at most one PRIMARY KEY. ^If the keywords PRIMARY KEY are added to a column definition, then the primary key for the table consists of that single column. ^Or, if a PRIMARY KEY clause is specified as a [table-constraint], then the primary key of the table consists of the list of columns specified as part of the PRIMARY KEY clause. ^If there is more than one PRIMARY KEY clause in a single CREATE TABLE statement, it is an error.

If a table has a single column primary key, and the declared type of that column is "INTEGER", then the column is known as an [INTEGER PRIMARY KEY]. See below for a description of the special properties and behaviours associated with an [INTEGER PRIMARY KEY].

^Each row in a table with a primary key must feature a unique combination of values in its primary key columns. ^For the purposes of determining the uniqueness of primary key values, NULL values are considered distinct from all other values, including other NULLs. ^If an [INSERT] or [UPDATE] statement attempts to modify the table content so that two or more rows feature identical primary key values, it is a constraint violation. According to the SQL standard, PRIMARY KEY should always imply NOT NULL. Unfortunately, due to a long-standing coding oversight, this is not the case in SQLite. ^Unless the column is an [INTEGER PRIMARY KEY] SQLite allows NULL values in a PRIMARY KEY column. We could change SQLite to conform to the standard (and we might do so in the future), but by the time the oversight was discovered, SQLite was in such wide use that we feared breaking legacy code if we fixed the problem. So for now we have chosen to continue allowing NULLs in PRIMARY KEY columns. Developers should be aware, however, that we may change SQLite to conform to the SQL standard in future and should design new programs accordingly.

^A UNIQUE constraint is similar to a PRIMARY KEY constraint, except that a single table may have any number of UNIQUE constraints. ^For each UNIQUE constraint on the table, each row must feature a unique combination of values in the columns identified by the UNIQUE constraint. ^As with PRIMARY KEY constraints, for the purposes of UNIQUE constraints NULL values are considered distinct from all other values (including other NULLs). ^If an [INSERT] or [UPDATE] statement attempts to modify the table content so that two or more rows feature identical values in a set of columns that are subject to a UNIQUE constraint, it is a constraint violation.

^[INTEGER PRIMARY KEY] columns aside, both UNIQUE and PRIMARY KEY constraints are implemented by creating an index in the database (in the same way as a [CREATE INDEX|"CREATE UNIQUE INDEX"] statement would). ^Such an index is used like any other index in the database to [optimizer|optimize queries]. As a result, there often no advantage (but significant overhead) in creating an index on a set of columns that are already collectively subject to a UNIQUE or PRIMARY KEY constraint. hd_fragment {ckconst} {CHECK} {CHECK constraint} {CHECK constraints}

^(A CHECK constraint may be attached to a column definition or specified as a table constraint. In practice it makes no difference.)^ ^(Each time a new row is inserted into the table or an existing row is updated, the expression associated with each CHECK constraint is evaluated and cast to a NUMERIC value in the same way as a [CAST expression]. If the result is zero (integer value 0 or real value 0.0), then a constraint violation has occurred.)^ ^If the CHECK expression evaluates to NULL, or any other non-zero value, it is not a constraint violation. ^The expression of a CHECK constraint may not contain a subquery.

CHECK constraints have been supported since [version 3.3.0]. Prior to version 3.3.0, CHECK constraints were parsed but not enforced.

^A NOT NULL constraint may only be attached to a column definition, not specified as a table constraint. Not surprisingly, ^(a NOT NULL constraint dictates that the associated column may not contain a NULL value. Attempting to set the column value to NULL when inserting a new row or updating an existing one causes a constraint violation.)^

Exactly how a constraint violation is dealt with is determined by the [conflict clause|constraint conflict resolution algorithm]. Each PRIMARY KEY, UNIQUE, NOT NULL and CHECK constraint has a default conflict resolution algorithm. ^PRIMARY KEY, UNIQUE and NOT NULL constraints may be explicitly assigned a default conflict resolution algorithm by including a [conflict-clause] in their definitions. ^Or, if a constraint definition does not include a [conflict-clause] or it is a CHECK constraint, the default conflict resolution algorithm is ABORT. ^Different constraints within the same table may have different default conflict resolution algorithms. See the section titled [ON CONFLICT] for additional information. hd_fragment rowid {INTEGER PRIMARY KEY} ROWID rowid

ROWIDs and the INTEGER PRIMARY KEY

^Every row of every SQLite table has a 64-bit signed integer key that uniquely identifies the row within its table. This integer is usually called the "rowid". ^The rowid value can be accessed using one of the special case-independent names "rowid", "oid", or "_rowid_" in place of a column name. ^If a table contains a user defined column named "rowid", "oid" or "_rowid_", then that name always refers the explicitly declared column and cannot be used to retrieve the integer rowid value.

The data for each table in SQLite is stored as a B-Tree structure containing an entry for each table row, using the rowid value as the key. This means that retrieving or sorting records by rowid is fast. Searching for a record with a specific rowid, or for all records with rowids within a specified range is around twice as fast as a similar search made by specifying any other PRIMARY KEY or indexed value.

^With one exception, if a table has a primary key that consists of a single column, and the declared type of that column is "INTEGER" in any mixture of upper and lower case, then the column becomes an alias for the rowid. Such a column is usually referred to as an "integer primary key". A PRIMARY KEY column only becomes an integer primary key if the declared type name is exactly "INTEGER". ^Other integer type names like "INT" or "BIGINT" or "SHORT INTEGER" or "UNSIGNED INTEGER" causes the primary key column to behave as an ordinary table column with integer [affinity] and a unique index, not as an alias for the rowid.

The exception mentioned above is that ^if the declaration of a column with declared type "INTEGER" includes an "PRIMARY KEY DESC" clause, it does not become an alias for the rowid and is not classified as an integer primary key. This quirk is not by design. It is due to a bug in early versions of SQLite. But fixing the bug could result in very serious backwards incompatibilities. The SQLite developers feel that goofy behavior in an corner case is far better than a compatibility break, so the original behavior is retained. This means that ^(the following three table declarations all cause the column "x" to be an alias for the rowid (an integer primary key):

)^

But ^(the following declaration does not result in "x" being an alias for the rowid:

)^

^Rowid values may be modified using an UPDATE statement in the same way as any other column value can, either using one of the built-in aliases ("rowid", "oid" or "_rowid_") or by using an alias created by an integer primary key. ^Similarly, an INSERT statement may provide a value to use as the rowid for each row inserted. ^(Unlike normal SQLite columns, an integer primary key or rowid column must contain integer values. Integer primary key or rowid columns are not able to hold floating point values, strings, BLOBs, or NULLs.)^

^If an UPDATE statement attempts to set an integer primary key or rowid column to a NULL or blob value, or to a string or real value that cannot be losslessly converted to an integer, a "datatype mismatch" error occurs and the statement is aborted. ^If an INSERT statement attempts to insert a blob value, or a string or real value that cannot be losslessly converted to an integer into an integer primary key or rowid column, a "datatype mismatch" error occurs and the statement is aborted.

^If an INSERT statement attempts to insert a NULL value into a rowid or integer primary key column, the system chooses an integer value to use as the rowid automatically. A detailed description of how this is done is provided separately.

^(The [parent key] of a [foreign key constraint] is not allowed to use the rowid. The parent key must used named columns only.)^

############################################################################## Section {CREATE TRIGGER} createtrigger {{CREATE TRIGGER}} BubbleDiagram create-trigger-stmt 1

^The CREATE TRIGGER statement is used to add triggers to the database schema. ^Triggers are database operations that are automatically performed when a specified database event occurs.

^A trigger may be specified to fire whenever a [DELETE], [INSERT], or [UPDATE] of a particular database table occurs, or whenever an [UPDATE] occurs on on one or more specified columns of a table.

^At this time SQLite supports only FOR EACH ROW triggers, not FOR EACH STATEMENT triggers. ^Hence explicitly specifying FOR EACH ROW is optional. ^FOR EACH ROW implies that the SQL statements specified in the trigger may be executed (depending on the WHEN clause) for each database row being inserted, updated or deleted by the statement causing the trigger to fire.

^(Both the WHEN clause and the trigger actions may access elements of the row being inserted, deleted or updated using references of the form "NEW.column-name" and "OLD.column-name", where column-name is the name of a column from the table that the trigger is associated with.)^ ^(OLD and NEW references may only be used in triggers on events for which they are relevant, as follows:

INSERT NEW references are valid
UPDATE NEW and OLD references are valid
DELETE OLD references are valid

)^

^If a WHEN clause is supplied, the SQL statements specified are only executed for rows for which the WHEN clause is true. ^If no WHEN clause is supplied, the SQL statements are executed for all rows.

^The BEFORE or AFTER keyword determines when the trigger actions will be executed relative to the insertion, modification or removal of the associated row.

^An [ON CONFLICT] clause may be specified as part of an [UPDATE] or [INSERT] action within the body of the trigger. ^However if an [ON CONFLICT] clause is specified as part of the statement causing the trigger to fire, then conflict handling policy of the outer statement is used instead.

^Triggers are automatically [DROP TRIGGER | dropped] when the table that they are associated with (the table-name table) is [DROP TABLE | dropped]. ^However if the trigger actions reference other tables, the trigger is not dropped or modified if those other tables are [DROP TABLE | dropped] or [ALTER TABLE | modified].

^Triggers are removed using the [DROP TRIGGER] statement.

Syntax Restrictions On UPDATE, DELETE, and INSERT Statements Within Triggers

^The [UPDATE], [DELETE], and [INSERT] statements within triggers do not support the full syntax for [UPDATE], [DELETE], and [INSERT] statements. The following restrictions apply:

hd_fragment instead_of_trigger {INSTEAD OF} {INSTEAD OF trigger}

INSTEAD OF trigger

^Triggers may be created on [views], as well as ordinary tables, by specifying INSTEAD OF in the CREATE TRIGGER statement. ^If one or more ON INSERT, ON DELETE or ON UPDATE triggers are defined on a view, then it is not an error to execute an INSERT, DELETE or UPDATE statement on the view, respectively. ^Instead, executing an INSERT, DELETE or UPDATE on the view causes the associated triggers to fire. ^The real tables underlying the view are not modified (except possibly explicitly, by a trigger program).

^Note that the [sqlite3_changes()] and [sqlite3_total_changes()] interfaces do not count INSTEAD OF trigger firings, but the [count_changes pragma] does count INSTEAD OF trigger firing.

Examples

^(Assuming that customer records are stored in the "customers" table, and that order records are stored in the "orders" table, the following trigger ensures that all associated orders are redirected when a customer changes his or her address:

Example { CREATE TRIGGER update_customer_address UPDATE OF address ON customers BEGIN UPDATE orders SET address = new.address WHERE customer_name = old.name; END; }

With this trigger installed, executing the statement:

Example { UPDATE customers SET address = '1 Main St.' WHERE name = 'Jack Jones'; }

causes the following to be automatically executed:

Example { UPDATE orders SET address = '1 Main St.' WHERE customer_name = 'Jack Jones'; })^ hd_fragment undef_before {undefined BEFORE trigger behavior}

Cautions On The Use Of BEFORE triggers

If a BEFORE UPDATE or BEFORE DELETE trigger modifies or deletes a row that was to have been updated or deleted, then the result of the subsequent update or delete operation is undefined. Furthermore, if a BEFORE trigger modifies or deletes a row, then it is undefined whether or not AFTER triggers that would have otherwise run on those rows will in fact run.

The value of NEW.rowid is undefined in a BEFORE INSERT trigger in which the rowid is not explicitly set to an integer.

Because of the behaviors described above, programmers are encouraged to prefer AFTER triggers over BEFORE triggers.

The RAISE() function

^(A special SQL function RAISE() may be used within a trigger-program,)^ with the following syntax

BubbleDiagram raise-function

^When one of the first three forms is called during trigger-program execution, the specified [ON CONFLICT] processing is performed (either ABORT, FAIL or ROLLBACK) and the current query terminates. An error code of [SQLITE_CONSTRAINT] is returned to the application, along with the specified error message.

^When RAISE(IGNORE) is called, the remainder of the current trigger program, the statement that caused the trigger program to execute and any subsequent trigger programs that would of been executed are abandoned. ^No database changes are rolled back. ^If the statement that caused the trigger program to execute is itself part of a trigger program, then that trigger program resumes execution at the beginning of the next step.

############################################################################### Section {CREATE VIEW} {createview} {{CREATE VIEW} view *views} BubbleDiagram create-view-stmt 1

^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.

^If the "TEMP" or "TEMPORARY" keyword occurs in between "CREATE" and "VIEW" then the view that is created is only visible to the process that opened the database and is automatically deleted when the database is closed.

^If a <database-name> is specified, then the view is created in the named database. ^It is an error to specify both a <database-name> and the TEMP keyword on a VIEW, unless the <database-name> is "temp". ^If no database name is specified, and the TEMP keyword is not present, the VIEW is created in the main database.

^You cannot [DELETE], [INSERT], or [UPDATE] a view. ^Views are read-only in SQLite. ^However, in many cases you can use an [INSTEAD OF trigger] on the view to accomplish the same thing. ^Views are removed with the [DROP VIEW] command.

############################################################################## Section {CREATE VIRTUAL TABLE} {createvtab} {{CREATE VIRTUAL TABLE}} BubbleDiagram create-virtual-table-stmt 1

A [virtual table] is an interface to an external storage or computation engine that appears to be a table but does not actually store information in the database file.

In general, you can do anything with a [virtual table] that can be done with an ordinary table, except that ^you cannot create indices or triggers on a virtual table. ^Some virtual table implementations might impose additional restrictions. For example, many virtual tables are read-only.

The <module-name> is the name of an object that implements the virtual table. ^The <module-name> must be registered with the SQLite database connection using [sqlite3_create_module()] or [sqlite3_create_module_v2()] prior to issuing the CREATE VIRTUAL TABLE statement. ^The module takes zero or more comma-separated arguments. ^The arguments can be just about any text as long as it has balanced parentheses. The argument syntax is sufficiently general that the arguments can be made to appear as [column definitions] in a traditional [CREATE TABLE] statement. ^SQLite passes the module arguments directly to the [xCreate] and [xConnect] methods of the module implementation without any interpretation. It is the responsibility of the module implementation to parse and interpret its own arguments.

^A virtual table is destroyed using the ordinary [DROP TABLE] statement. There is no DROP VIRTUAL TABLE statement.

############################################################################## Section DELETE delete {DELETE *DELETEs} BubbleDiagram delete-stmt 1 BubbleDiagram qualified-table-name

The DELETE command removes records from the table identified by the qualified-table-name.

^If the WHERE clause is not present, all records in the table are deleted. ^If a WHERE clause is supplied, then only those rows for which the result of evaluating the WHERE clause as a [boolean expression| boolean expression is true] are deleted.

Restrictions on DELETE Statements Within CREATE TRIGGER

The following restrictions apply to DELETE statements that occur within the body of a [CREATE TRIGGER] statement:

Optional LIMIT and ORDER BY clauses

^(If SQLite is compiled with the [SQLITE_ENABLE_UPDATE_DELETE_LIMIT] compile-time option, then the syntax of the DELETE statement is extended by the addition of optional ORDER BY and LIMIT clauses:)^

BubbleDiagram delete-stmt-limited

^If a DELETE statement has a LIMIT clause, the maximum number of rows that will be deleted is found by evaluating the accompanying expression and casting it to an integer value. ^If the result of the evaluating the LIMIT clause cannot be losslessly converted to an integer value, it is an error. ^A negative LIMIT value is interpreted as "no limit". ^(If the DELETE statement also has an OFFSET clause, then it is similarly evaluated and cast to an integer value. Again, it is an error if the value cannot be losslessly converted to an integer.)^ ^If there is no OFFSET clause, or the calculated integer value is negative, the effective OFFSET value is zero.

^(If the DELETE statement has an ORDER BY clause, then all rows that would be deleted in the absence of the LIMIT clause are sorted according to the ORDER BY. The first M rows, where M is the value found by evaluating the OFFSET clause expression, are skipped, and the following N, where N is the value of the LIMIT expression, are deleted.)^ ^If there are less than N rows remaining after taking the OFFSET clause into account, or if the LIMIT clause evaluated to a negative value, then all remaining rows are deleted.

^If the DELETE statement has no ORDER BY clause, then all rows that would be deleted in the absence of the LIMIT clause are assembled in an arbitrary order before applying the LIMIT and OFFSET clauses to determine the subset that are actually deleted.

^(The ORDER BY clause on an DELETE statement is used only to determine which rows fall within the LIMIT. The order in which rows are deleted is arbitrary and is not influenced by the ORDER BY clause.)^ hd_fragment truncateopt {truncate optimization}

The Truncate Optimization

^When the WHERE is omitted from a DELETE statement and the table being deleted has no triggers, SQLite uses an optimization to erase the entire table content without having to visit each row of the table individually. This "truncate" optimization makes the delete run much faster. Prior to SQLite [version 3.6.5], the truncate optimization also meant that the [sqlite3_changes()] and [sqlite3_total_changes()] interfaces and the [count_changes pragma] will not actually return the number of deleted rows. That problem has been fixed as of [version 3.6.5].

^The truncate optimization can be permanently disabled for all queries by recompiling SQLite with the [SQLITE_OMIT_TRUNCATE_OPTIMIZATION] compile-time switch.

The truncate optimization can also be disabled at runtime using the [sqlite3_set_authorizer()] interface. ^If an authorizer callback returns [SQLITE_IGNORE] for an [SQLITE_DELETE] action code, then the DELETE operation will proceed but the truncate optimization will be bypassed and rows will be deleted one by one.

############################################################################### Section {DETACH DATABASE} detach *DETACH BubbleDiagram detach-stmt 1

^This statement detaches an additional database connection previously attached using the [ATTACH] statement. ^It is possible to have the same database file attached multiple times using different names, and detaching one connection to a file will leave the others intact.

^This statement will fail if SQLite is in the middle of a transaction.

############################################################################## Section {DROP INDEX} dropindex {{DROP INDEX}} BubbleDiagram drop-index-stmt 1

^The DROP INDEX statement removes an index added with the [CREATE INDEX] statement. The index 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 {{DROP TABLE}} BubbleDiagram drop-table-stmt 1

^The DROP TABLE statement removes a table added with the [CREATE TABLE] statement. The name specified is the table name. ^The dropped table is completely removed from the database schema and the disk file. The table can not be recovered. ^All indices and triggers associated with the table are also deleted.

^The optional IF EXISTS clause suppresses the error that would normally result if the table does not exist.

^If [foreign key constraints] are enabled, a DROP TABLE command performs an implicit [DELETE | DELETE FROM <tbl>] command before removing the table from the database schema. ^Any triggers attached to the table are dropped from the database schema before the implicit DELETE FROM <tbl> is executed, so this cannot cause any triggers to fire. By contrast, ^an implicit DELETE FROM <tbl> does cause any configured [foreign key actions] to take place. ^If the implicit DELETE FROM <tbl> executed as part of a DROP TABLE command violates any immediate foreign key constraints, an error is returned and the table is not dropped. ^If the implicit DELETE FROM <tbl> causes any deferred foreign key constraints to be violated, and the violations still exist when the transaction is committed, an error is returned at the time of commit. ############################################################################## Section {DROP TRIGGER} droptrigger {{DROP TRIGGER}} BubbleDiagram drop-trigger-stmt 1

^The DROP TRIGGER statement removes a trigger created by the [CREATE TRIGGER] statement. ^Once removed, the trigger definition is no longer present in the sqlite_master (or sqlite_temp_master) table and is not fired by any subsequent INSERT, UPDATE or DELETE statements.

^Note that triggers are automatically dropped when the associated table is dropped. ############################################################################## Section {DROP VIEW} dropview {{DROP VIEW}} BubbleDiagram drop-view-stmt 1

^The DROP VIEW statement removes a view created by the [CREATE VIEW] statement. ^The view definition is removed from the database schema, but no actual data in the underlying base tables is modified.

^(The view to drop is identified by the view-name and optional database-name specified as part of the DROP VIEW statement. This reference is resolved using the standard procedure for [object resolution].)^

^If the specified view cannot be found and the IF EXISTS clause is not present, it is an error. ^If the specified view cannot be found and an IF EXISTS clause is present in the DROP VIEW statement, then the statement is a no-op. ############################################################################## Section {Database Object Name Resolution} {naming} {{object resolution}}

In SQLite, a database object (a table, index, trigger or view) is identified by the name of the object and the name of the database that it resides in. Database objects may reside in the main database, the temp database, or in an [ATTACH|attached database].

The syntax of the [DROP TABLE], [DROP INDEX], [DROP VIEW], [DROP TRIGGER], [REINDEX], [ALTER TABLE] and many other commands all permit the user to specify a database object either by its name alone, or by a combination of its name and the name of its database. ^(If no database is specified as part of the object reference, then SQLite searches the main, temp and all attached databases for an object with a matching name. The temp database is searched first, followed by the main database, followed all attached databases in the order that they were attached. The reference resolves to the first match found.)^ For example:

^(
      /* Add a table named 't1' to the temp, main and an attached database */
      ATTACH 'file.db' AS aux;
      CREATE TABLE t1(x, y);
      CREATE TEMP TABLE t1(x, y);
      CREATE TABLE aux.t1(x, y);

      DROP TABLE t1;         /* Drop table in temp database */
      DROP TABLE t1;         /* Drop table in main database */
      DROP TABLE t1;         /* Drop table in aux database */
)^

^If a database name is specified as part of an object reference, it must be either "main", or "temp" or the name of an attached database. ^Like other SQL identifiers, database names are case-insensitive. ^If a database name is specified, then only the named database is searched for the named object.

Most object references may only resolve to a specific type of object (for example a reference that is part of a DROP TABLE statement may only resolve to a table object, not an index, trigger or view). However in some contexts (e.g. [REINDEX]) an object reference may be resolve to more than one type of object. ^When searching database schemas for a named object, objects of types that cannot be used in the context of the reference are always ignored. ############################################################################## Section EXPLAIN explain EXPLAIN BubbleDiagram sql-stmt

^An SQL statement can be preceded by the keyword "EXPLAIN" or by the phrase "EXPLAIN QUERY PLAN". ^Either modification causes the SQL statement to behave as a query and to return information about how the SQL statement would have operated if the EXPLAIN keyword or phrase had been omitted.

The output from EXPLAIN and EXPLAIN QUERY PLAN is intended for interactive analysis and troubleshooting only. The details of the output format are subject to change from one release of SQLite to the next. Applications should not use EXPLAIN or EXPLAIN QUERY PLAN since their exact behavior is variable and only partially documented.

^When the EXPLAIN keyword appears by itself it causes the statement to behave as a query that returns the sequence of [virtual machine instructions] it would have used to execute the command had the EXPLAIN keyword not been present. ^When the EXPLAIN QUERY PLAN phrase appears, the statement returns high-level information regarding the query plan that would have been used. The EXPLAIN QUERY PLAN command is described in [explain query plan|more detail here]. ############################################################################## Section expression expr {*expression {expression syntax}} BubbleDiagram expr 1 BubbleDiagram literal-value BubbleDiagram signed-number BubbleDiagram raise-function

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 subcomponents of most other commands.

hd_fragment binaryops {binary operators}

Operators

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

||
*    /    %
+    -
<<   >>   &    |
<    <=   >    >=
=    ==   !=   <>   IS   IS NOT   IN   LIKE   GLOB   MATCH   REGEXP
AND   
OR
)^

^(Supported unary prefix operators are these:

-    +    ~    NOT
)^ hd_fragment collateop {COLLATE operator}

^The COLLATE operator is a unary postfix operator that assigns a [collating sequence] to an expression. ^The COLLATE operator has a higher precedence (binds more tightly) than any prefix unary operator or any binary operator. ^The collating sequence set by the COLLATE operator overrides the collating sequence determined by the COLLATE clause in a table [column definition]. See the [collating sequence| detailed discussion on collating sequences] in the [datatype | Datatype In SQLite3] document for additional information.

hd_puts "

^The unary operator [Operator +] is a no-op. ^It can be applied to strings, numbers, blobs or NULL and it always returns a result with the same value as the operand.

"

Note that there are two variations of the equals and not equals operators. ^Equals can be either hd_puts "[Operator =] or [Operator ==]. ^The non-equals operator can be either [Operator !=] or [Operator {<>}]. ^The [Operator ||] operator is \"concatenate\" - it joins together the two strings of its operands. ^The operator [Operator %] outputs the value of its left operand modulo its right operand.

^The result of any binary operator is either a numeric value or NULL, except for the [Operator ||] concatenation operator which always evaluates to either NULL or a text value.

" hd_fragment {isisnot} {IS operator} {IS NOT operator} hd_puts "

^The [Operator IS] and [Operator {IS NOT}] operators work like [Operator =] and [Operator !=] except when one or both of the operands are NULL. ^In this case, if both operands are NULL, then the IS operator evaluates to 1 (true) and the IS NOT operator evaluates to 0 (false). ^If one operand is NULL and the other is not, then the IS operator evaluates to 0 (false) and the IS NOT operator is 1 (true). ^It is not possible for an IS or IS NOT expression to evaluate to NULL. ^Operators [Operator IS] and [Operator {IS NOT}] have the same precedence as [Operator =]." hd_fragment litvalue {literal value}

Literal Values

^A literal value is a constant of some kind. ^Literal values may be integers, floating point numbers, strings, BLOBs, or NULLs.

The syntax for integer and floating point literals (collectively "numeric literals") is shown by the following diagram:

BubbleDiagram numeric-literal

^(If a numeric literal has a decimal point or an exponentiation clause, then it is a floating point literal. Otherwise is it is an integer literal.)^ ^The "E" character that begins the exponentiation clause of a floating point literal can be either upper or lower case. ^(The "." character is always used as the decimal point even if the locale setting specifies "," for this role - the use of "," for the decimal point would result in syntactic ambiguity.)^

^A string constant is formed by enclosing the string in single quotes ('). ^A single quote within the string can be encoded by putting two single quotes in a row - as in Pascal. C-style escapes using the backslash character are not supported because they are not standard SQL. ^BLOB literals are string literals containing hexadecimal data and preceded by a single "x" or "X" character. ^(For example:

X'53514C697465'
)^

^A literal value can also be the token "NULL".

hd_fragment varparam parameter parameters {bound parameter} {bound parameters}

Parameters

A "variable" or "parameter" token specifies a placeholder in the expression for a value that is filled in at runtime using the [sqlite3_bind_blob() | sqlite3_bind()] family of C/C++ interfaces. Parameters can take several forms:

?NNN ^(A question mark followed by a number NNN holds a spot for the NNN-th parameter. NNN must be between 1 and [SQLITE_MAX_VARIABLE_NUMBER].)^
? ^A question mark that is not followed by a number creates a parameter with a number one greater than the largest parameter number already assigned. ^If this means the parameter number is greater than [SQLITE_MAX_VARIABLE_NUMBER], it is an error.
:AAAA ^A colon followed by an identifier name holds a spot for a [sqlite3_bind_parameter_name|named parameter] with the name :AAAA. ^(Named parameters are also numbered. The number assigned is one greater than the largest parameter number already assigned.)^ ^If this means the parameter would be assigned a number greater than [SQLITE_MAX_VARIABLE_NUMBER], it is an error. To avoid confusion, it is best to avoid mixing named and numbered parameters.
@AAAA ^An "at" sign works exactly like a colon, except that the name of the parameter created is @AAAA.
$AAAA ^A dollar-sign followed by an identifier name also holds a spot for a named parameter with the name $AAAA. ^(The identifier name in this case can include one or more occurrences of "::" and a suffix enclosed in "(...)" containing any text at all.)^ This syntax is the form of a variable name in the [http://www.tcl.tk/ | Tcl programming language]. The presence of this syntax results from the fact that SQLite is really a [Tcl extension] that has escaped into the wild.

^Parameters that are not assigned values using [sqlite3_bind_blob() | sqlite3_bind()] are treated as NULL.

^The maximum parameter number is set at compile-time by the [SQLITE_MAX_VARIABLE_NUMBER] macro. ^(An individual [database connections] D can reduce its maximum parameter number below the compile-time maximum using the [sqlite3_limit](D, [SQLITE_LIMIT_VARIABLE_NUMBER],...) interface.)^

hd_fragment like LIKE ESCAPE

The LIKE and GLOB operators

^The LIKE operator does a pattern matching comparison. ^The operand to the right of the LIKE operator contains the pattern and the left hand operand contains the string to match against the pattern. hd_puts "^A percent symbol (\"%\") in the LIKE pattern matches any sequence of zero or more characters in the string. ^An underscore (\"_\") in the LIKE pattern matches any single character in the string. ^(Any other character matches itself or its lower/upper case equivalent (i.e. case-insensitive matching).)^ (A bug: ^SQLite only understands upper/lower case for ASCII characters by default. ^The LIKE operator is case sensitive by default for unicode characters that are beyond the ASCII range. For example, ^the expression 'a' LIKE 'A' is TRUE but 'æ' LIKE 'Æ' is FALSE.)

"

^If the optional ESCAPE clause is present, then the expression following the ESCAPE keyword must evaluate to a string consisting of a single character. ^This character may be used in the LIKE pattern to include literal percent or underscore characters. ^The escape character followed by a percent symbol (%), underscore (_), or a second instance of the escape character itself matches a literal percent symbol, underscore, or a single escape character, respectively.

^The infix LIKE operator is implemented by calling the application-defined SQL functions [like(Y,X)] or [like(Y,X,Z)].

^The LIKE operator can be made case sensitive using the [case_sensitive_like pragma].

hd_fragment glob GLOB

^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. ^The infix GLOB operator is implemented by calling the function [glob(Y,X)] and can be modified by overriding that function.

hd_fragment regexp REGEXP

^The REGEXP operator is a special syntax for the regexp() user function. ^No regexp() user function is defined by default and so use of the REGEXP operator will normally result in an error message. ^If a [application-defined SQL function] named "regexp" is added at run-time, that function will be called in order to implement the REGEXP operator.

hd_fragment match MATCH

^The MATCH operator is a special syntax for the match() application-defined function. ^The default match() function implementation raises an exception and is not really useful for anything. ^But extensions can override the match() function with more helpful logic.

hd_fragment between BETWEEN

The BETWEEN operator

^(The BETWEEN operator is logically equivalent to a pair of comparisons. "x BETWEEN y AND z" is equivalent to "x>=y AND x<=z" except that with BETWEEN, the x expression is only evaluated once.)^ ^The precedence of the BETWEEN operator is the same as the precedence as operators == and != and LIKE and groups left to right. hd_fragment case {CASE expression}

The CASE expression

A CASE expression serves a role similar to IF-THEN-ELSE in other programming languages.

The optional expression that occurs in between the CASE keyword and the first WHEN keyword is called the "base" expression. ^There are two basic forms of the CASE expression: those with a base expression and those without.

^In a CASE without a base expression, each WHEN expression is evaluated and the result treated as a boolean, starting with the leftmost and continuing to the right. ^The result of the CASE expression is the evaluation of the THEN expression that corresponds to the first WHEN expression that evaluates to true. ^Or, if none of the WHEN expressions evaluate to true, the result of evaluating the ELSE expression, if any. ^If there is no ELSE expression and none of the WHEN expressions are true, then the overall result is NULL.

^A NULL result is considered untrue when evaluating WHEN terms.

^In a CASE with a base expression, the base expression is evaluated just once and the result is compared against the evaluation of each WHEN expression from left to right. ^The result of the CASE expression is the evaluation of the THEN expression that corresponds to the first WHEN expression for which the comparison is true. ^Or, if none of the WHEN expressions evaluate to a value equal to the base expression, the result of evaluating the ELSE expression, if any. ^If there is no ELSE expression and none of the WHEN expressions produce a result equal to the base expression, the overall result is NULL.

^When comparing a base expression against a WHEN expression, the same collating sequence, affinity, and NULL-handling rules apply as if the base expression and WHEN expression are respectively the left- and right-hand operands of an = operator.

^If the base expression is NULL then the result of the CASE is always the result of evaluating the ELSE expression if it exists, or NULL if it does not.

^Both forms of the CASE expression use lazy, or short-circuit, evaluation.

^(The only difference between the following two CASE expressions is that the x expression is evaluated exactly once in the first example but might be evaluated multiple times in the second:

)^ hd_fragment in_op {IN operator} {NOT IN operator}

The IN and NOT IN operators

^The IN and NOT IN operators take a single scalar operand on the left and a vector operand on the right formed by an explicit list of zero or more scalars or by a single subquery. ^When the right operand of an IN or NOT IN operator is a subquery, the subquery must have a single result column. ^When the right operand is an empty set, the result of IN is false and the result of NOT IN is true, regardless of the left operand and even if the left operand is NULL. ^(The result of an IN or NOT IN operator is determined by the following matrix:

Left operand
is NULL
Right operand
contains NULL
Right operand
is an empty set
Left operand found
within right operand
Result of
IN operator
Result of
NOT IN operator
no no no no false true
does not matter no yes no false true
no does not matter no yes true false
no yes no no NULL NULL
yes does not matter no does not matter NULL NULL
)^

^Note that SQLite allows the parenthesized list of scalar values on the right-hand side of an IN or NOT IN operator to be an empty list but most other SQL database database engines and the SQL92 standard require the list to contain at least one element.

hd_fragment in_op {EXISTS operator} {NOT EXISTS operator}

The EXISTS operator

^The EXISTS operator always evaluates to one of the integer values 0 and 1. ^If executing the SELECT statement specified as the right-hand operand of the EXISTS operator would return one or more rows, then the EXISTS operator evaluates to 1. ^If executing the SELECT would return no rows at all, then the EXISTS operator evaluates to 0.

^The number of columns in each row returned by the SELECT statement (if any) and the specific values returned have no effect on the results of the EXISTS operator. ^In particular, rows containing NULL values are not handled any differently from rows without NULL values.

Scalar Subqueries

^A [SELECT] statement enclosed in parentheses may appear as a scalar quantity. ^A [SELECT] used as a scalar quantity must return a result set with a single column. ^The result of the expression is the value of the only column in the first row returned by the SELECT statement. ^If the SELECT yields more than one result row, all rows after the first are ignored. ^If the SELECT yields no rows, then the value of the expression is NULL.

^All types of [SELECT] statement, including aggregate and compound SELECT queries (queries with keywords like UNION or EXCEPT) are allowed as scalar subqueries.

Table Column Names

^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 integer key (the [rowid]) 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. ^The rowid can be used anywhere a regular column can be used.

^A [SELECT] statement used as either a scalar subquery or as the right-hand operand of an IN, NOT IN or EXISTS expression may contain references to columns in the outer query. Such a subquery is known as a correlated subquery. ^A correlated subquery is reevaluated each time its result is required. ^An uncorrelated subquery is evaluated only once and the result reused as necessary. hd_fragment castexpr {CAST expression}

CAST expressions

A CAST expression is used to convert the value of <expr> to a different [storage class] in a similar way to the conversion that takes place when a [column affinity] is applied to a value. ^Application of a CAST expression is different to application of a column affinity, as with a CAST expression the storage class conversion is forced even if it is lossy and irrreversible.

^If the value of <expr> is NULL, then the result of the CAST expression is also NULL. ^Otherwise, the storage class of the result value is determined by applying the [rules for determining column affinity] to the <type-name> specified as part of the CAST expression.
Affinity of <type-name> Conversion Processing
NONE ^Casting a value to a <type-name> with no affinity causes the value to be converted into a BLOB. ^Casting to a BLOB consists of first casting the value to TEXT in the [encoding] of the database connection, then interpreting the resulting byte sequence as a BLOB instead of as TEXT.
TEXT ^To cast a BLOB value to TEXT, the sequence of bytes that make up the BLOB is interpreted as text encoded using the database encoding.

^Casting an INTEGER or REAL value into TEXT renders the value as if via [sqlite3_snprintf()] except that the resulting TEXT uses the [encoding] of the database connection.

REAL ^When casting a BLOB value to a REAL, the value is first converted to TEXT.

^When casting a TEXT value to REAL, the longest possible prefix of the value that can be interpreted as a real number is extracted from the TEXT value and the remainder ignored. ^Any leading spaces in the TEXT value are ignored when converging from TEXT to REAL. ^(If there is no prefix that can be interpreted as a real number, the result of the conversion is 0.0.)^

INTEGER ^When casting a BLOB value to INTEGER, the value is first converted to TEXT.

^When casting a TEXT value to INTEGER, the longest possible prefix of the value that can be interpreted as an integer number is extracted from the TEXT value and the remainder ignored. ^Any leading spaces in the TEXT value when converting from TEXT to INTEGER are ignored. ^If there is no prefix that can be interpreted as an integer number, the result of the conversion is 0.

^A cast of a REAL value into an INTEGER will truncate the fractional part of the REAL. ^If an REAL is too large to be represented as an INTEGER then the result of the cast is the largest negative integer: -9223372036854775808.

NUMERIC ^Casting a TEXT or BLOB value into NUMERIC first does a forced conversion into REAL but then further converts the result into INTEGER if and only if the conversion from REAL to INTEGER is lossless and reversible. This is the only context in SQLite where the NUMERIC and INTEGER [affinities] behave differently.

^Casting a REAL or INTEGER value to NUMERIC is a no-op, even if a real value could be losslessly converted to an integer.

^Note that the result from casting any non-BLOB value into a BLOB and the result from casting any BLOB value into a non-BLOB value may be different depending on whether the database [encoding] is UTF-8, UTF-16be, or UTF-16le. hd_fragment booleanexpr {boolean expression}

Boolean Expressions

The SQL language features several contexts where an expression is evaluated and the result converted to a boolean (true or false) value. These contexts are:

^(To convert the results of an SQL expression to a boolean value, SQLite first casts the result to a NUMERIC value in the same way as a [CAST expression]. A NULL or zero value (integer value 0 or real value 0.0) is considered to be false. All other values are considered true.)^

^(For example, the values NULL, 0.0, 0, 'english' and '0' are all considered to be false.)^ ^(Values 1, 1.0, 0.1, -0.1 and '1english' are considered to be true.)^

Functions

^Both [corefunc|simple] and [aggfunc|aggregate] functions are supported. (For presentation purposes, simple functions are further subdivided into [corefunc | core functions] and [datefunc | date-time functions].) ^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.

############################################################################## Section {Core Functions} corefunc {*corefunc} proc funcdef {syntax keywords desc} { hd_puts {} regsub -all {\s+} [string trim $syntax] {

} syntax regsub -all {\(([^*)]+)\)} $syntax {(\1)} syntax regsub -all {,} $syntax {,} syntax regsub -all {\.\.\.} $syntax {...} syntax hd_puts "" if {[llength $keywords]==0} { regexp {[a-z_]+} $syntax name hd_fragment $name *$name "${name}() SQL function" } else { set fragname [lindex $keywords 0] regsub -all {[^a-z]} $fragname {} fragname hd_fragment $fragname eval hd_keywords [string map {\n { }} $keywords] } hd_puts "$syntax" hd_puts {} hd_resolve $desc hd_puts {} }

The core functions shown below are available by default. [datefunc | Date & Time functions] and [aggfunc | aggregate functions] are documented separately. An application may define additional functions written in C and added to the database engine using the [sqlite3_create_function()] API.

funcdef {abs(X)} {} { ^The abs(X) function returns the absolute value of the numeric argument X. ^Abs(X) returns NULL if X is NULL. ^(Abs(X) return 0.0 if X is a string or blob that cannot be converted to a numeric value.)^ ^If X is the integer -9223372036854775807 then abs(X) throws an integer overflow error since there is no equivalent positive 64-bit two complement value. } funcdef {changes()} {} { ^The changes() function returns the number of database rows that were changed or inserted or deleted by the most recently completed INSERT, DELETE, or UPDATE statement, exclusive of statements in lower-level triggers. ^The changes() SQL function is a wrapper around the [sqlite3_changes()] C/C++ function and hence follows the same rules for counting changes. } funcdef {coalesce(X,Y,...)} {} { ^The coalesce() function returns a copy of its first non-NULL argument, or NULL if all arguments are NULL. ^Coalesce() must be at least 2 arguments. } funcdef {glob(X,Y)} {} { ^The glob(X,Y) function is equivalent to the expression "Y GLOB X". Note that the X and Y arguments are reversed in the glob() function relative to the infix [GLOB] operator. ^If the [sqlite3_create_function()] interface is used to override the glob(X,Y) function with an alternative implementation then the [GLOB] operator will invoke the alternative implementation. } funcdef {ifnull(X,Y)} {} { ^The ifnull() function returns a copy of its first non-NULL argument, or NULL if both arguments are NULL. ^Ifnull() must have exactly 2 arguments. ^The ifnull() function is equivalent to [coalesce()] with two arguments. } funcdef {hex(X)} {} { ^The hex() function interprets its argument as a BLOB and returns a string which is the upper-case hexadecimal rendering of the content of that blob. } funcdef {last_insert_rowid()} {} { ^The last_insert_rowid() function returns the [ROWID] of the last row insert from the database connection which invoked the function. ^The last_insert_rowid() SQL function is a wrapper around the [sqlite3_last_insert_rowid()] C/C++ interface function. } funcdef {length(X)} {} { ^The length(X) function returns the length of X in characters if X is a string, or in bytes if X is a blob. ^If X is NULL then length(X) is NULL. ^If X is numeric then length(X) returns the length of a string representation of X. } funcdef {like(X,Y) like(X,Y,Z)} {} { ^The like() function is used to implement the "Y LIKE X [ESCAPE Z]" expression. ^If the optional ESCAPE clause is present, then the like() function is invoked with three arguments. ^Otherwise, it is invoked with two arguments only. Note that the X and Y parameters are reversed in the like() function relative to the infix [LIKE] operator. ^The [sqlite3_create_function()] interface can be used to override the like() function and thereby change the operation of the [LIKE] operator. When overriding the like() function, it may be important to override both the two and three argument versions of the like() function. Otherwise, different code may be called to implement the [LIKE] operator depending on whether or not an ESCAPE clause was specified. } funcdef {load_extension(X) load_extension(X,Y)} {} { ^The load_extension(X,Y) function loads SQLite extensions out of the shared library file named X using the entry point Y. ^The result of load_extension() is always a NULL. ^If Y is omitted then the default entry point of sqlite3_extension_init is used. ^The load_extension() function raises an exception if the extension fails to load or initialize correctly.

^The load_extension() function will fail if the extension attempts to modify or delete a SQL function or collating sequence. ^The extension can add new functions or collating sequences, but cannot modify or delete existing functions or collating sequences because those functions and/or collating sequences might be used elsewhere in the currently running SQL statement. To load an extension that changes or deletes functions or collating sequences, use the [sqlite3_load_extension()] C-language API.

} funcdef {lower(X)} {} { ^The lower(X) function returns a copy of string X with all ASCII characters converted to lower case. ^The default built-in lower() function works for ASCII characters only. To do case conversions on non-ASCII characters, load the ICU extension. } funcdef {ltrim(X) ltrim(X,Y)} {} { ^The ltrim(X,Y) function returns a string formed by removing any and all characters that appear in Y from the left side of X. ^If the Y argument is omitted, ltrim(X) removes spaces from the left side of X. } funcdef {max(X,Y,...)} {*maxCoreFunc *max {max() SQL function}} { ^The multi-argument max() function returns the argument with the maximum value, or return NULL if any argument is NULL. ^The multi-argument max() function searches its arguments from left to right for an argument that defines a collating function and uses that collating function for all string comparisons. ^If none of the arguments to max() define a collating function, then the BINARY collating function is used. Note that max() is a simple function when it has 2 or more arguments but operates as an [minAggFunc | aggregate function] if given only a single argument. } funcdef {min(X,Y,...)} {*minCoreFunc *min {min() SQL function}} { ^The multi-argument min() function returns the argument with the minimum value. ^The multi-argument min() function searches its arguments from left to right for an argument that defines a collating function and uses that collating function for all string comparisons. ^If none of the arguments to min() define a collating function, then the BINARY collating function is used. Note that min() is a simple function when it has 2 or more arguments but operates as an [maxAggFunc | aggregate function] if given only a single argument. } funcdef {nullif(X,Y)} {} { ^The nullif(X,Y) function returns its first argument if the arguments are different and NULL if the arguments are the same. ^The nullif(X,Y) function searches its arguments from left to right for an argument that defines a collating function and uses that collating function for all string comparisons. ^If neither argument to nullif() defines a collating function then the BINARY is used. } funcdef {quote(X)} {} { ^The quote(X) function returns a string which is the value of its argument suitable for inclusion into another SQL statement. ^Strings are surrounded by single-quotes with escapes on interior quotes as needed. ^BLOBs are encoded as hexadecimal literals. } funcdef {random()} {} { ^The random() function returns a pseudo-random integer between -9223372036854775808 and +9223372036854775807. } funcdef {randomblob(N)} {} { ^The randomblob(N) function return an N-byte blob containing pseudo-random bytes. ^If N is less than 1 then a 1-byte random blob is returned.

Hint: applications can generate globally unique identifiers using this function together with [hex()] and/or [lower()] like this:

hex(randomblob(16))

lower(hex(randomblob(16)))
} funcdef {replace(X,Y,Z)} {} { ^The replace(X,Y,Z) function returns a string formed by substituting string Z for every occurrence of string Y in string X. ^The [BINARY] collating sequence is used for comparisons. ^If Y is an empty string then return X unchanged. ^If Z is not initially a string, it is cast to a UTF-8 string prior to processing. } funcdef {round(X) round(X,Y)} {} { ^The round(X,Y) function returns a string representation of the floating-point value X rounded to Y digits to the right of the decimal point. ^If the Y argument is omitted, the X value is truncated to an integer. } funcdef {rtrim(X) rtrim(X,Y)} {} { ^The rtrim(X,Y) function returns a string formed by removing any and all characters that appear in Y from the right side of X. ^If the Y argument is omitted, rtrim(X) removes spaces from the right side of X. } funcdef {soundex(X)} {} { ^The soundex(X) function returns a string that is the soundex encoding of the string X. ^The string "?000" is returned if the argument is NULL or contains no ASCII alphabetic characters. ^(This function is omitted from SQLite by default. It is only available if the [SQLITE_SOUNDEX] compile-time option is used when SQLite is built.)^ } funcdef {sqlite_compileoption_get(N)} {} { ^The sqlite_compileoption_get() SQL function is a wrapper around the [sqlite3_compileoption_get()] C/C++ function. ^This routine returns the N-th compile-time option used to build SQLite or NULL if N is out of range. See also the [compile_options pragma]. } funcdef {sqlite_compileoption_used(X)} {} { ^The sqlite_compileoption_used() SQL function is a wrapper around the [sqlite3_compileoption_used()] C/C++ function. ^When the argument X to sqlite_compileoption_used(X) is a string which is the name of a compile-time option, this routine returns true (1) or false (0) depending on whether or not that option was used during the build. } funcdef {sqlite_source_id()} {} { ^The sqlite_source_id() function returns a string that identifies the specific version of the source code that was used to build the SQLite library. ^The string returned by sqlite_source_id() begins with the date and time that the source code was checked in and is follows by an SHA1 hash that uniquely identifies the source tree. ^This function is an SQL wrapper around the [sqlite3_sourceid()] C interface. } funcdef {sqlite_version()} {} { ^The sqlite_version() function returns the version string for the SQLite library that is running. ^This function is an SQL wrapper around the [sqlite3_libversion()] C-interface. } funcdef {substr(X,Y,Z) substr(X,Y)} {} { ^The substr(X,Y,Z) function returns a substring of input string X that begins with the Y-th character and which is Z characters long. ^If Z is omitted then substr(X,Y) returns all characters through the end of the string X beginning with the Y-th. ^The left-most character of X is number 1. ^If Y is negative then the first character of the substring is found by counting from the right rather than the left. ^If Z is negative then the abs(Z) characters preceding the Y-th character are returned. ^If X is a string then characters indices refer to actual UTF-8 characters. ^If X is a BLOB then the indices refer to bytes. } funcdef {total_changes()} {} { ^The total_changes() function returns the number of row changes caused by INSERT, UPDATE or DELETE statements since the current database connection was opened. ^This function is a wrapper around the [sqlite3_total_changes()] C/C++ interface. } funcdef {trim(X) trim(X,Y)} {} { ^The trim(X,Y) function returns a string formed by removing any and all characters that appear in Y from both ends of X. ^If the Y argument is omitted, trim(X) removes spaces from both ends of X. } funcdef {typeof(X)} {} { ^The typeof(X) function returns a string that indicates the [datatype] of the expression X: "null", "integer", "real", "text", or "blob". } funcdef {upper(X)} {} { ^The upper(X) function returns a copy of input string X in which all lower-case ASCII characters are converted to their upper-case equivalent. } funcdef {zeroblob(N)} {} { ^The zeroblob(N) function returns a BLOB consisting of N bytes of 0x00. SQLite manages these zeroblobs very efficiently. Zeroblobs can be used to reserve space for a BLOB that is later written using [sqlite3_blob_open() | incremental BLOB I/O]. ^This SQL function is implemented using the [sqlite3_result_zeroblob()] routine from the C/C++ interface. }
############################################################################## Section {Date And Time Functions} datefunc {*datefunc} hd_keywords {date() SQL function} {time() SQL function} hd_keywords {datetime() SQL function} {julianday() SQL function} hd_keywords {strftime() SQL function}

SQLite supports five date and time functions as follows:

  1. ^(date(timestring, modifier, modifier, ...))^
  2. ^(time(timestring, modifier, modifier, ...))^
  3. ^(datetime(timestring, modifier, modifier, ...))^
  4. ^(julianday(timestring, modifier, modifier, ...))^
  5. ^(strftime(format, timestring, modifier, modifier, ...))^

^All five date and time functions take a time string as an argument. ^The time string is followed by zero or more modifiers. ^The strftime() function also takes a format string as its first argument.

The date and time functions use a subset of [http://en.wikipedia.org/wiki/ISO_8601 | IS0-8601] date and time formats. ^The date() function returns the date in this format: YYYY-MM-DD. ^The time() function returns the time as HH:MM:SS. ^The datetime() function returns "YYYY-MM-DD HH:MM:SS". ^(The julianday() function returns the [http://en.wikipedia.org/wiki/Julian_day | Julian day] - the number of days since noon in Greenwich on November 24, 4714 B.C. ([http://en.wikipedia.org/wiki/Proleptic_Gregorian_calendar | Proleptic Gregorian calendar]).)^ ^The strftime() routine returns the date formatted according to the format string specified as the first argument. ^The format string supports the most common substitutions found in the [http://opengroup.org/onlinepubs/007908799/xsh/strftime.html | strftime() function] from the standard C library plus two new substitutions, %f and %J. ^(The following is a complete list of valid strftime() substitutions:

%d day of month: 00
%f fractional seconds: SS.SSS
%H hour: 00-24
%j day of year: 001-366
%J Julian day number
%m month: 01-12
%M minute: 00-59
%s seconds since 1970-01-01
%S seconds: 00-59
%w day of week 0-6 with Sunday==0
%W week of year: 00-53
%Y year: 0000-9999
%% %
)^

^(Notice that all other date and time functions can be expressed in terms of strftime():

FunctionEquivalent strftime()
date(...) strftime('%Y-%m-%d', ...)
time(...) strftime('%H:%M:%S', ...)
datetime(...) strftime('%Y-%m-%d %H:%M:%S', ...)
julianday(...) strftime('%J', ...)
)^

The only reasons for providing functions other than strftime() is for convenience and for efficiency.

Time Strings

^(A time string can be in any of the following formats:

  1. YYYY-MM-DD
  2. YYYY-MM-DD HH:MM
  3. YYYY-MM-DD HH:MM:SS
  4. YYYY-MM-DD HH:MM:SS.SSS
  5. YYYY-MM-DDTHH:MM
  6. YYYY-MM-DDTHH:MM:SS
  7. YYYY-MM-DDTHH:MM:SS.SSS
  8. HH:MM
  9. HH:MM:SS
  10. HH:MM:SS.SSS
  11. now
  12. DDDDDDDDDD
)^

^In formats 5 through 7, the "T" is a literal character separating the date and the time, as required by [http://www.w3c.org/TR/NOTE-datetime | ISO-8601]. ^Formats 8 through 10 that specify only a time assume a date of 2000-01-01. Format 11, the string 'now', is converted into the current date and time as obtained from the xCurrentTime method of the [sqlite3_vfs] object in use. ^[http://en.wikipedia.org/wiki/Coordinated_Universal_Time | Universal Coordinated Time (UTC)] is used. ^Format 12 is the [http://en.wikipedia.org/wiki/Julian_day | Julian day number] expressed as a floating point value.

Modifiers

^The time string can be followed by zero or more modifiers that alter date and/or time. ^Each modifier is a transformation that is applied to the time value to its left. ^Modifiers are applied from left to right; order is important. ^(The available modifiers are as follows.

  1. NNN days
  2. NNN hours
  3. NNN minutes
  4. NNN.NNNN seconds
  5. NNN months
  6. NNN years
  7. start of month
  8. start of year
  9. start of day
  10. weekday N
  11. unixepoch
  12. localtime
  13. utc
)^

^The first six modifiers (1 through 6) simply add the specified amount of time to the date and time specified by the preceding timestring and modifiers. ^Note that "±NNN months" works by rendering the original date into the YYYY-MM-DD format, adding the ±NNN to the MM month value, then normalizing the result. ^Thus, for example, the data 2001-03-31 modified by '+1 month' initially yields 2001-04-31, but April only has 30 days so the date is normalized to 2001-05-01. ^A similar effect occurs when the original date is February 29 of a leapyear and the modifier is ±N years where N is not a multiple of four.

^The "start of" modifiers (7 through 9) shift the date backwards to the beginning of the current month, year or day.

^The "weekday" modifier advances the date forward to the next date where the weekday number is N. Sunday is 0, Monday is 1, and so forth.

^The "unixepoch" modifier (11) only works if it immediately follows a timestring in the DDDDDDDDDD format. ^This modifier causes the DDDDDDDDDD to be interpreted not as a Julian day number as it normally would be, but as [http://en.wikipedia.org/wiki/Unix_time | Unix Time] - the number of seconds since 1970. If the "unixepoch" modifier does not follow a timestring of the form DDDDDDDDDD which expresses the number of seconds since 1970 or if other modifiers separate the "unixepoch" modifier from prior DDDDDDDDDD then the behavior is undefined. Due to precision limitations imposed by the implementations use of 64-bit integers, the "unixepoch" modifier only works for dates between 0000-01-01 00:00:00 and 5352-11-01 10:52:47 (unix times of -62167219200 through 10675199167).

^The "localtime" modifier (12) assumes the time string to its left is in Universal Coordinated Time (UTC) and adjusts the time string so that it displays localtime. If "localtime" follows a time that is not UTC, then the behavior is undefined. ^(The "utc" is the opposite of "localtime". "utc" assumes that the string to its left is in the local timezone and adjusts that string to be in UTC.)^ If the prior string is not in localtime, then the result of "utc" is undefined.

Examples

^(

Compute the current date.

SELECT date('now');
)^ ^(

Compute the last day of the current month.

SELECT date('now','start of month','+1 month','-1 day');
)^ ^(

Compute the date and time given a unix timestamp 1092941466.

SELECT datetime(1092941466, 'unixepoch');
)^ ^(

Compute the date and time given a unix timestamp 1092941466, and compensate for your local timezone.

SELECT datetime(1092941466, 'unixepoch', 'localtime');
)^ ^(

Compute the current unix timestamp.

SELECT strftime('%s','now');
)^ ^(

Compute the number of days since the signing of the US Declaration of Independence.

SELECT julianday('now') - julianday('1776-07-04');
)^ ^(

Compute the number of seconds since a particular moment in 2004:

SELECT strftime('%s','now') - strftime('%s','2004-01-01 02:34:56');
)^ ^(

Compute the date of the first Tuesday in October for the current year.

SELECT date('now','start of year','+9 months','weekday 2');
)^ ^(

Compute the time since the unix epoch in seconds (like strftime('%s','now') except includes fractional part):

SELECT (julianday('now') - 2440587.5)*86400.0;
)^

Caveats And Bugs

The computation of local time depends heavily on the whim of politicians and is thus difficult to get correct for all locales. ^In this implementation, the standard C library function localtime_r() is used to assist in the calculation of local time. ^(The localtime_r() C function normally only works for years between 1970 and 2037. For dates outside this range, SQLite attempts to map the year into an equivalent year within this range, do the calculation, then map the year back.)^

^(These functions only work for dates between 0000-01-01 00:00:00 and 9999-12-31 23:59:59 (julidan day numbers 1721059.5 through 5373484.5).)^ For dates outside that range, the results of these functions are undefined.

Non-Vista Windows platforms only support one set of DST rules. Vista only supports two. Therefore, on these platforms, historical DST calculations will be incorrect. For example, in the US, in 2007 the DST rules changed. Non-Vista Windows platforms apply the new 2007 DST rules to all previous years as well. Vista does somewhat better getting results correct back to 1986, when the rules were also changed.

All internal computations assume the [http://en.wikipedia.org/wiki/Gregorian_calendar | Gregorian calendar] system. It is also assumed that every day is exactly 86400 seconds in duration.

############################################################################## Section {Aggregate Functions} aggfunc {*aggfunc}

The aggregate functions shown below are available by default. Additional aggregate functions written in C may be added using the [sqlite3_create_function()] API.

^In any aggregate function that takes a single argument, that argument can be preceded by the keyword DISTINCT. ^In such cases, duplicate elements are filtered before being passed into the aggregate function. ^For example, the function "count(distinct X)" will return the number of distinct values of column X instead of the total number of non-null values in column X.

funcdef {avg(X)} {*avg {avg() aggregate function}} { ^The avg() function returns the average value of all non-NULL X within a group. ^String and BLOB values that do not look like numbers are interpreted as 0. ^The result of avg() is always a floating point value as long as at there is at least one non-NULL input even if all inputs are integers. ^The result of avg() is NULL if and only if there are no non-NULL inputs. } funcdef {count(X) count(*)} {*count {count() aggregate function}} { ^The count(X) function returns a count of the number of times that X is not NULL in a group. ^The count(*) function (with no arguments) returns the total number of rows in the group. } funcdef {group_concat(X) group_concat(X,Y)} { *group_concat {group_concat() aggregate function} } { ^The group_concat() function returns a string which is the concatenation of all non-NULL values of X. ^If parameter Y is present then it is used as the separator between instances of X. ^A comma (",") is used as the separator if Y is omitted. The order of the concatenated elements is arbitrary. } funcdef {max(X)} {*maxAggFunc *agg_max {max() aggregate function}} { ^The max() aggregate function returns the maximum value of all values in the group. ^The maximum value is the value that would be returned last in an ORDER BY on the same column. ^Aggregate max() returns NULL if and only if there are no non-NULL values in the group. } funcdef {min(X)} {*minAggFunc *agg_min {min() aggregate function}} { ^The min() aggregate function returns the minimum non-NULL value of all values in the group. ^The minimum value is the first non-NULL value that would appear in an ORDER BY of the column. ^Aggregate min() returns NULL if and only if there are no non-NULL values in the group. } funcdef {sum(X) total(X)} { *sumFunc *sum *total {sum() aggregate function} {total() aggregate function} } { ^The sum() and total() aggregate functions return sum of all non-NULL values in the group. ^If there are no non-NULL input rows then sum() returns NULL but total() returns 0.0. NULL is not normally a helpful result for the sum of no rows but the SQL standard requires it and most other SQL database engines implement sum() that way so SQLite does it in the same way in order to be compatible. The non-standard total() function is provided as a convenient way to work around this design problem in the SQL language.

^The result of total() is always a floating point value. ^The result of sum() is an integer value if all non-NULL inputs are integers. ^If any input to sum() is neither an integer or a NULL then sum() returns a floating point value which might be an approximation to the true sum.

^Sum() will throw an "integer overflow" exception if all inputs are integers or NULL and an integer overflow occurs at any point during the computation. ^Total() never throws an integer overflow. }

############################################################################## Section INSERT insert {INSERT *INSERTs} BubbleDiagram insert-stmt 1

The INSERT statement comes in three basic forms.

^The optional conflict-clause allows the specification of an alternative constraint conflict resolution algorithm to use during this one INSERT 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".

^(The optional "database-name." prefix on the table-name is support for top-level INSERT statements only.)^ ^The table name must be unqualified for INSERT statements that occur within [CREATE TRIGGER] statements. ^Similarly, the "DEFAULT VALUES" form of the INSERT statement is supported for top-level INSERT statements only and not for INSERT statements within triggers.

############################################################################## Section {ON CONFLICT clause} conflict {{conflict clause} {ON CONFLICT}} BubbleDiagram conflict-clause

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 command. ^For the INSERT and UPDATE commands, the keywords "ON CONFLICT" are replaced by "OR" so that the syntax reads more naturally. For example, instead of "INSERT ON CONFLICT IGNORE" we have "INSERT OR IGNORE". The keywords change but the meaning of the clause is the same either way.

The ON CONFLICT clause applies to UNIQUE, NOT NULL, and CHECK constraints (and to PRIMARY KEY constraints which for the purposes of this section are the same thing as UNIQUE constraints). The ON CONFLICT algorithm does not apply to [FOREIGN KEY constraints]. There are five conflict resolution algorithm choices: ROLLBACK, ABORT, FAIL, IGNORE, and REPLACE. ^The default conflict resolution algorithm is ABORT. This is what they mean:

ROLLBACK

^When an applicable constraint violation occurs, the ROLLBACK resolution algorithm aborts the current SQL statement with an SQLITE_CONSTRAINT error and rolls back the current transaction. ^If no transaction is active (other than the implied transaction that is created on every command) then the ROLLBACK resolution algorithm works the same as the ABORT algorithm.

ABORT

^When an applicable constraint violation occurs, the ABORT resolution algorithm aborts the current SQL statement with an SQLITE_CONSTRAIT error and backs out any changes made by the current SQL statement; but changes caused by prior SQL statements within the same transaction are preserved and the transaction remains active. This is the default behavior and the behavior proscribed the SQL standard.

FAIL

^When an applicable constraint violation occurs, the FAIL resolution algorithm aborts the current SQL statement with an SQLITE_CONSTRAINT error. ^But the FAIL resolution does not back out prior changes of the SQL statement that failed nor does it end the transaction. ^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 an applicable constraint violation occurs, the IGNORE resolution algorithm skips the one row that contains the constraint violation and continues processing subsequent rows of the SQL statement as if nothing went wrong. Other rows before and after the row that contained the constraint violation are inserted or updated normally. ^No error is returned when the IGNORE conflict resolution algorithm is used.

REPLACE

^When a UNIQUE constraint violation occurs, the REPLACE algorithm deletes pre-existing rows that are causing the constraint violation prior to inserting or updating the current row and the command continues executing normally. ^If a NOT NULL constraint violation occurs, the REPLACE conflict resolution replaces the NULL value with he default value for that column, or if the column has no default value, then the ABORT algorithm is used. ^If a CHECK constraint violation occurs, the REPLACE conflict resolution algorithm always works like ABORT.

^When the REPLACE conflict resolution strategy deletes rows in order to satisfy a constraint, [CREATE TRIGGER | delete triggers] fire if and only if [recursive_triggers pragma | recursive triggers] are enabled.

^The [sqlite3_update_hook | update hook] is not invoked for rows that are deleted by the REPLACE conflict resolution strategy. ^Nor does REPLACE increment the [sqlite3_changes | change counter]. The exceptional behaviors defined in this paragraph might change in a future release.

^The algorithm specified in the OR clause of a INSERT or UPDATE overrides any algorithm specified in a CREATE TABLE. ^If no algorithm is specified anywhere, the ABORT algorithm is used.

############################################################################## Section REINDEX reindex REINDEX BubbleDiagram reindex-stmt 1

^The REINDEX command is used to delete and recreate indices from scratch. This is useful when the definition of a collation sequence has changed.

^If the REINDEX keyword is not followed by a collation-sequence or database object identifier, then all indices in all attached databases are rebuilt.

^If the REINDEX keyword is followed by a collation-sequence name, then all indices in all attached databases that use the named collation sequences are recreated.

^Or, if the argument attached to the REINDEX identifies a specific database table, then all indices attached to the database table are rebuilt. ^If it identifies a specific database index, then just that index is recreated.

^If no database-name is specified and there exists both a table or index and a collation sequence of the specified name, SQLite interprets this as a request to rebuild the indices that use the named collation sequence. This ambiguity in the syntax may be avoided by always specifying a database-name when reindexing a specific table or index. ############################################################################### Section REPLACE replace REPLACE

^The REPLACE command is an alias for the "[ON CONFLICT | INSERT OR REPLACE]" variant of the [INSERT] command. This alias is provided for compatibility other SQL database engines. See the [INSERT] command documentation for additional information.

############################################################################### Section SELECT select {SELECT query} BubbleDiagram select-stmt 1 BubbleDiagram select-core BubbleDiagram result-column BubbleDiagram join-source BubbleDiagram single-source BubbleDiagram join-op BubbleDiagram join-constraint BubbleDiagram ordering-term BubbleDiagram compound-operator

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 SELECT statement is the most complicated command in the SQL language. To make the description easier to follow, some of the passages below describe the way the data returned by a SELECT statement is determined as a series of steps. It is important to keep in mind that this is purely illustrative - in practice neither SQLite nor any other SQL engine is required to follow this or any other specific process.

Simple Select Processing

The syntax for a simple SELECT statement is depicted in the [select-core syntax diagram]. Generating the results of a simple SELECT statement is presented as a four step process in the description below:

  1. [FROM clause] processing: The input data for the simple SELECT is determined. The input data is either implicitly a single row with 0 columns (if there is no FROM clause) or is determined by analyzing the [join-source syntax diagram|join-source] specification that follows an explicit FROM clause.

  2. [WHERE clause] processing: The input data is filtered using the WHERE clause expression.

  3. [GROUP BY|GROUP BY, HAVING and result-column expression] processing: The set of result rows is computed by aggregating the data according to any GROUP BY clause and calculating the result-set expressions for the rows of the filtered input dataset.

  4. [DISTINCT|DISTINCT/ALL keyword] processing: If the query is a "SELECT DISTINCT" query, duplicate rows are removed from the set of result rows.

There are two types of simple SELECT statement - aggregate and non-aggregate queries. ^A simple SELECT statement is an aggregate query if it contains either a GROUP BY clause or one or more aggregate functions in the result-set. ^Otherwise, if a simple SELECT contains no aggregate functions or a GROUP BY clause, it is a non-aggregate query.

1. Determination of input data (FROM clause processing). hd_fragment fromclause hd_keywords {FROM clause}

The input data used by a simple SELECT query is a set of N rows each M columns wide.

^(If the FROM clause is omitted from a simple SELECT statement, then the input data is implicitly a single row zero columns wide)^ (i.e. N=1 and M=0).

If a FROM clause is specified, the data on which a simple SELECT query operates comes from the one or more tables or subqueries (SELECT statements in parenthesis) specified following the FROM keyword. ^A sub-select specified in the join-source following the FROM clause in a simple SELECT statement is handled as if it was a table containing the data returned by executing the sub-select statement. ^Each column of the sub-select dataset inherits the [collation|collation sequence] and [affinity] of the corresponding expression in the sub-select statement.

^If there is only a single table in the join-source following the FROM clause, then the input data used by the SELECT statement is the contents of the named table. ^If there is more than one table specified as part of the join-source following the FROM keyword, then the contents of each named table are joined into a single dataset for the simple SELECT statement to operate on. Exactly how the data is combined depends on the specific [join-op] and [join-constraint] used to connect the tables or subqueries together.

All joins in SQLite are based on the cartesian product of the left and right-hand datasets. ^The columns of the cartesian product dataset are, in order, all the columns of the left-hand dataset followed by all the columns of the right-hand dataset. ^There is a row in the cartesian product dataset formed by combining each unique combination of a row from the left-hand and right-hand datasets. ^(In other words, if the left-hand dataset consists of Nlhs rows of Mlhs columns, and the right-hand dataset of Nrhs rows of Mrhs columns, then the cartesian product is a dataset of Nlhs.Nrhs rows, each containing Mlhs+Mrhs columns.)^

^If the join-op is "CROSS JOIN", "INNER JOIN", "JOIN" or a comma (",") and there is no ON or USING clause, then the result of the join is simply the cartesian product of the left and right-hand datasets. ^There is no difference between the "INNER JOIN", "JOIN" and "," join operators. ^(The "CROSS JOIN" join operator produces the same data as the "INNER JOIN", "JOIN" and "," operators)^, but is handled slightly differently by the query optimizer. Otherwise, it is the cartesian product modified according to one or more of the following bullet points:

^(When more than two tables are joined together as part of a FROM clause, the join operations are processed in order from left to right. In other words, the FROM clause (A join-op-1 B join-op-2 C) is computed as ((A join-op-1 B) join-op-2 C).)^

2. WHERE clause filtering. hd_fragment whereclause hd_keywords {WHERE clause}

^(If a WHERE clause is specified, the WHERE expression is evaluated for each row in the input data as a [boolean expression]. All rows for which the WHERE clause expression evaluates to false are excluded from the dataset before continuing.)^

3. Generation of the set of result rows. hd_fragment resultset hd_keywords {result-set expressions} {GROUP BY}

Once the input data from the FROM clause has been filtered by the WHERE clause expression (if any), the set of result rows for the simple SELECT are calculated. Exactly how this is done depends on whether the simple SELECT is an aggregate or non-aggregate query, and whether or not a GROUP BY clause was specified.

The list of expressions between the SELECT and FROM keywords is known as the result expression list. ^If a result expression is the special expression "*" then all columns in the input data are substituted for that one expression. ^(If the expression is the alias of a table or subquery in the FROM clause followed by ".*" then all columns from the named table or subquery are substituted for the single expression.)^ ^(It is an error to use a "*" or "alias.*" expression in any context other than than a result expression list.)^ ^(It is also an error to use a "*" or "alias.*" expression in a simple SELECT query that does not have a FROM clause.)^

^(The number of columns in the rows returned by a simple SELECT statement is equal to the number of expressions in the result expression list after substitution of * and alias.* expressions.)^ Each result row is calculated by evaluating the expressions in the result expression list with respect to a single row of input data or, for aggregate queries, with respect to a group of rows.

4. Removal of duplicate rows (DISTINCT processing). hd_fragment distinct hd_keywords {DISTINCT}

^One of the ALL or DISTINCT keywords may follow the SELECT keyword in a simple SELECT statement. ^If the simple SELECT is a SELECT ALL, then the entire set of result rows are returned by the SELECT. ^If neither ALL or DISTINCT are present, then the behaviour is as if ALL were specified. ^If the simple SELECT is a SELECT DISTINCT, then duplicate rows are removed from the set of result rows before it is returned. ^For the purposes of detecting duplicate rows, two NULL values are considered to be equal. ^The normal rules for selecting a collation sequence to compare text values with apply.

Compound Select Statements hd_fragment compound hd_keywords {compound select} {compound query}

Two or more simple SELECT statements may be connected together to form a compound SELECT using the UNION, UNION ALL, INTERSECT or EXCEPT operator. ^In a compound SELECT, all the constituent SELECTs must return the same number of result columns. ^As the components of a compound SELECT must be simple SELECT statements, they may not contain ORDER BY or LIMIT clauses. ^ORDER BY and LIMIT clauses may only occur at the end of the entire compound SELECT.

^A compound SELECT created using UNION ALL operator returns all the rows from the SELECT to the left of the UNION ALL operator, and all the rows from the SELECT to the right of it. ^The UNION operator works the same way as UNION ALL, except that duplicate rows are removed from the final result set. ^The INTERSECT operator returns the intersection of the results of the left and right SELECTs. ^The EXCEPT operator returns the subset of rows returned by the left SELECT that are not also returned by the right-hand SELECT. ^Duplicate rows are removed from the results of INTERSECT and EXCEPT operators before the result set is returned.

^For the purposes of determining duplicate rows for the results of compound SELECT operators, NULL values are considered equal to other NULL values and distinct from all non-NULL values. ^The collation sequence used to compare two text values is determined as if the columns of the left and right-hand SELECT statements were the left and right-hand operands of the equals (=) operator, except that greater precedence is not assigned to a collation sequence specified with the postfix COLLATE operator. ^No affinity transformations are applied to any values when comparing rows as part of a compound SELECT.

^(When three or more simple SELECTs are connected into a compound SELECT, they group from left to right. In other words, if "A", "B" and "C" are all simple SELECT statements, (A op B op C) is processed as ((A op B) op C).)^

hd_fragment orderby {order by}

ORDER BY and LIMIT/OFFSET Clauses

If a SELECT statement that returns more than one row does not have an ORDER BY clause, the order in which the rows are returned is undefined. Or, if a SELECT statement does have an ORDER BY clause, then the list of expressions attached to the ORDER BY determine the order in which rows are returned to the user. ^Rows are first sorted based on the results of evaluating the left-most expression in the ORDER BY list, then ties are broken by evaluating the second left-most expression and so on. The order in which two rows for which all ORDER BY expressions evaluate to equal values are returned is undefined. ^Each ORDER BY expression may be optionally followed by one of the keywords ASC (smaller values are returned first) or DESC (larger values are returned first). ^If neither ASC or DESC are specified, rows are sorted in ascending (smaller values first) order by default.

Each ORDER BY expression is processed as follows:

  1. ^If the ORDER BY expression is a constant integer K then the expression is considered an alias for the K-th column of the result set (columns are numbered from left to right starting with 1).

  2. ^If the ORDER BY expression is an identifier that corresponds to the alias of one of the output columns, then the expression is considered an alias for that column.

  3. ^Otherwise, if the ORDER BY expression is any other expression, it is evaluated and the the returned value used to order the output rows. ^If the SELECT statement is a simple SELECT, then an ORDER BY may contain any arbitrary expressions. ^However, if the SELECT is a compound SELECT, then ORDER BY expressions that are not aliases to output columns must be exactly the same as an expression used as an output column.

^For the purposes of sorting rows, values are compared in the same way as for [comparison expressions]. The collation sequence used to compare two text values is determined as follows:

  1. ^If the ORDER BY expression is assigned a collation sequence using the postfix [COLLATE operator], then the specified collation sequence is used.

  2. ^Otherwise, if the ORDER BY expression is an alias to an expression that has been assigned a collation sequence using the postfix [COLLATE operator], then the collation sequence assigned to the aliased expression is used.

  3. ^Otherwise, if the ORDER BY expression is a column or an alias of an expression that is a column, then the default collation sequence for the column is used.

  4. ^Otherwise, the [BINARY] collation sequence is used.

In a compound SELECT statement, all ORDER BY expressions are handled as aliases for one of the result columns of the compound SELECT. ^(If an ORDER BY expression is not an integer alias, then SQLite searches the left-most SELECT in the compound for a result column that matches either the second or third rules above. If a match is found, the search stops and the expression is handled as an alias for the result column that it has been matched against. Otherwise, the next SELECT to the right is tried, and so on.)^ ^If no matching expression can be found in the result columns of any constituent SELECT, it is an error. ^Each term of the ORDER BY clause is processed separately and may be matched against result columns from different SELECT statements in the compound.

The LIMIT clause is used to place an upper bound on the number of rows returned by a SELECT statement. ^Any scalar expression may be used in the LIMIT clause, so long as it evaluates to an integer or a value that can be losslessly converted to an integer. ^If the expression evaluates to a NULL value or any other value that cannot be losslessly converted to an integer, an error is returned. ^If the LIMIT expression evaluates to a negative value, then there is no upper bound on the number of rows returned. ^Otherwise, the SELECT returns the first N rows of its result set only, where N is the value that the LIMIT expression evaluates to. ^Or, if the SELECT statement would return less than N rows without a LIMIT clause, then the entire result set is returned.

^The expression attached to the optional OFFSET clause that may follow a LIMIT clause must also evaluate to an integer, or a value that can be losslessly converted to an integer. ^If an expression has an OFFSET clause, then the first M rows are omitted from the result set returned by the SELECT statement and the next N rows are returned, where M and N are the values that the OFFSET and LIMIT clauses evaluate to, respectively. ^Or, if the SELECT would return less than M+N rows if it did not have a LIMIT clause, then the first M rows are skipped and the remaining rows (if any) are returned. ^If the OFFSET clause evaluates to a negative value, the results are the same as if it had evaluated to zero.

^Instead of a separate OFFSET clause, the LIMIT clause may specify two scalar expressions separated by a comma. ^In this case, the first expression is used as the OFFSET expression and the second as the LIMIT expression. This is counter-intuitive, as when using the OFFSET clause the second of the two expressions is the OFFSET and the first the LIMIT. This is intentional - it maximizes compatibility with other SQL database systems. ############################################################################## Section UPDATE update {UPDATE *UPDATEs} BubbleDiagram update-stmt 1 BubbleDiagram qualified-table-name

^An UPDATE statement is used to modify a subset of the values stored in zero or more rows of the database table identified by the qualified-table-name specified as part of the UPDATE statement.

^If the UPDATE statement does not have a WHERE clause, all rows in the table are modified by the UPDATE. ^Otherwise, the UPDATE affects only those rows for which the result of evaluating the WHERE clause expression as a [boolean expression|boolean expression is true]. ^It is not an error if the WHERE clause does not evaluate to true for any row in the table - this just means that the UPDATE statement affects zero rows.

The modifications made to each row affected by an UPDATE statement are determined by the list of assignments following the SET keyword. Each assignment specifies a column name to the left of the equals sign and a scalar expression to the right. ^For each affected row, the named columns are set to the values found by evaluating the corresponding scalar expressions. ^If a single column-name appears more than once in the list of assignment expressions, all but the rightmost occurence is ignored. ^Columns that do not appear in the list of assignments are left unmodified. ^The scalar expressions may refer to columns of the row being updated. ^In this case all scalar expressions are evaluated before any assignments are made.

^The optional conflict-clause allows the user to nominate a specific constraint conflict resolution algorithm to use during this one UPDATE command. Refer to the section entitled [ON CONFLICT] for additional information.

Restrictions on UPDATE Statements Within CREATE TRIGGER

The following additional syntax restrictions apply to UPDATE statements that occur within the body of a [CREATE TRIGGER] statement.

Optional LIMIT and ORDER BY Clauses

^(If SQLite is built with the [SQLITE_ENABLE_UPDATE_DELETE_LIMIT] compile-time option then the syntax of the UPDATE statement is extended with optional ORDER BY and LIMIT clauses)^ as follows:

BubbleDiagram update-stmt-limited

^If an UPDATE statement has a LIMIT clause, the maximum number of rows that will be updated is found by evaluating the accompanying expression and casting it to an integer value. ^A negative value is interpreted as "no limit".

^If the LIMIT expression evaluates to non-negative value N and the UPDATE statement has an ORDER BY clause, then all rows that would be updated in the absence of the LIMIT clause are sorted according to the ORDER BY and the first N updated. ^(If the UPDATE statement also has an OFFSET clause, then it is similarly evaluated and cast to an integer value. If the OFFSET expression evaluates to a non-negative value M, then the first M rows are skipped and the following N rows updated instead.)^

^If the UPDATE statement has no ORDER BY clause, then all rows that would be updated in the absence of the LIMIT clause are assembled in an arbitrary order before applying the LIMIT and OFFSET clauses to determine which are actually updated.

^(The ORDER BY clause on an UPDATE statement is used only to determine which rows fall within the LIMIT. The order in which rows are modified is arbitrary and is not influenced by the ORDER BY clause.)^ ############################################################################## Section VACUUM vacuum VACUUM BubbleDiagram vacuum-stmt 1

The VACUUM command rebuilds the entire database. There are several reasons an application might do this:

^(VACUUM only works on the main database. It is not possible to VACUUM an attached database file.)^

^The VACUUM command works by copying the contents of the database into a temporary database file and then overwriting the original with the contents of the temporary file. ^When overwriting the original, a rollback journal or [write-ahead log] WAL file is used just as it would be for any other database transaction. ^This means that when VACUUMing a database, as much as twice the size of the original database file is required in free disk space.

^The VACUUM command may change the [ROWID | ROWIDs] of entries in any tables that do not have an explicit [INTEGER PRIMARY KEY].

^A VACUUM will fail if there is an open transaction, or if there are one or more active SQL statements when it is run.

^(As of SQLite version 3.1, an alternative to using the VACUUM command to reclaim space after data has been deleted is auto-vacuum mode, enabled using the [auto_vacuum] pragma.)^ ^When [auto_vacuum] is enabled for a database free pages may be reclaimed after deleting data, causing the file to shrink, without rebuilding the entire database using VACUUM. However, using [auto_vacuum] can lead to extra database file fragmentation. And [auto_vacuum] does not compact partially filled pages of the database as VACUUM does.

############################################################################## Section {INDEXED BY} indexedby {{INDEXED BY} {NOT INDEXED}}

^The INDEXED BY phrase is a SQL extension found only in SQLite which can be used to verify that the correct indices are being used on a [DELETE], [SELECT], or [UPDATE] statement. ^The INDEXED BY phrase always follows the name of a table that SQLite will be reading. The INDEXED BY phrase can be seen in the following syntax diagrams:

BubbleDiagram qualified-table-name BubbleDiagram single-source

^The "INDEXED BY index-name" clause specifies that the named index must be used in order to look up values on the preceding table. ^If index-name does not exist or cannot be used for the query, then the preparation of the SQL statement fails. ^(The "NOT INDEXED" clause specifies that no index shall be used when accessing the preceding table, including implied indices create by UNIQUE and PRIMARY KEY constraints. However, the INTEGER PRIMARY KEY can still be used to look up entries even when "NOT INDEXED" is specified.)^

Some SQL database engines provide non-standard "hint" mechanisms which can be used to give the query optimizer clues about what indices it should use for a particular statement. The INDEX BY clause of SQLite is not a hinting mechanism and it should not be used as such. ^The INDEXED BY clause does not give the optimizer hints about which index to use; it gives the optimizer a requirement of which index to use. ^If the query optimizer is unable to use the index specified by the INDEX BY clause, then the query will fail with an error.

The INDEXED BY clause is not intended for use in tuning the performance of a query. The intent of the INDEXED BY clause is to raise a run-time error if a schema change, such as dropping or creating an index, causes the query plan for a time-sensitive query to change. The INDEXED BY clause is designed to help detect undesirable query plan changes during regression testing. Developers are admonished to omit all use of INDEXED BY during application design, implementation, testing, and tuning. If INDEXED BY is to be used at all, it should be inserted at the very end of the development process when "locking down" a design.

See Also:

The [sqlite3_stmt_status()] C/C++ interface together with the [SQLITE_STMTSTATUS_FULLSCAN_STEP] and [SQLITE_STMTSTATUS_SORT] verbs can be used to detect at run-time when an SQL statement is not making effective use of indices. Many applications may prefer to use the [sqlite3_stmt_status()] interface to detect index misuse rather than the INDEXED BY phrase described here.

############################################################################# # A list of keywords. A asterisk occurs after the keyword if it is on # the fallback list. # set keyword_list [lsort { ABORT ACTION ADD AFTER ALL ALTER ANALYZE AND AS ASC ATTACH AUTOINCREMENT BEFORE BEGIN BETWEEN BY CASCADE CASE CAST CHECK COLLATE COLUMN COMMIT CONFLICT CONSTRAINT CREATE CROSS CURRENT_DATE CURRENT_TIME CURRENT_TIMESTAMP DATABASE DEFAULT DEFERRED DEFERRABLE DELETE DESC DETACH DISTINCT DROP END EACH ELSE ESCAPE EXCEPT EXCLUSIVE EXISTS EXPLAIN FAIL FOR FOREIGN FROM FULL GLOB GROUP HAVING IF IGNORE IMMEDIATE IN INDEX INDEXED INITIALLY INNER INSERT INSTEAD INTERSECT INTO IS ISNULL JOIN KEY LEFT LIKE LIMIT MATCH NATURAL NO NOT NOTNULL NULL OF OFFSET ON OR ORDER OUTER PLAN PRAGMA PRIMARY QUERY RAISE REFERENCES REGEXP REINDEX RELEASE RENAME REPLACE RESTRICT RIGHT ROLLBACK ROW SAVEPOINT SELECT SET TABLE TEMP TEMPORARY THEN TO TRANSACTION TRIGGER UNION UNIQUE UPDATE USING VACUUM VALUES VIEW VIRTUAL WHEN WHERE }] hd_puts {
} Section {SQLite Keywords} keywords {{*SQL keyword} {SQL keywords}} hd_puts {
}

The SQL standard specifies a huge number of keywords which may not be used as the names of tables, indices, columns, databases, user-defined functions, collations, virtual table modules, or any other named object. The list of keywords is so long that few people can remember them all. For most SQL code, your safest bet is to never use any English language word as the name of a user-defined object.

If you want to use a keyword as a name, you need to quote it. There are three ways of quoting keywords in SQLite:

'keyword' ^A keyword in single quotes is a string literal.
"keyword" ^A keyword in double-quotes is an identifier.
[keyword] ^A keyword enclosed in square brackets is an identifier. This is not standard SQL. This quoting mechanism is used by MS Access and SQL Server and is included in SQLite for compatibility.
`keyword` ^A keyword enclosed in grave accents (ASCII code 96) is an identifier. This is not standard SQL. This quoting mechanism is used by MySQL and is included in SQLite for compatibility.

For resilience when confronted with historical SQL statements, SQLite will sometimes bend the quoting rules above:

Programmers are cautioned not to use the two exceptions described in the previous bullets. We emphasize that they exist only so that old and ill-formed SQL statements will run correctly. Future versions of SQLite might change to raise errors instead of accepting the malformed statements covered by the exceptions above.

SQLite adds new keywords from time to time when it takes on new features. So to prevent your code from being broken by future enhancements, you should normally quote any identifier that is an English language word, even if you do not have to.

The list below shows all possible keywords used by any build of SQLite regardless of [compile-time options]. Most reasonable configurations use most or all of these keywords, but some keywords may be omitted when SQL language features are disabled. ^(Regardless of the compile-time configuration, any identifier that is not on the following hd_puts [llength $keyword_list] element list is not a keyword to the SQL parser in SQLite:

set n [llength $keyword_list] set nCol 5 set nRow [expr {($n+$nCol-1)/$nCol}] set i 0 foreach word $keyword_list { if {$i==$nRow} { hd_puts "" set i 1 } else { incr i } hd_puts "$word
\n" }
)^