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 keywords is also provided. The SQL language syntax is described by syntax diagrams.

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

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

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_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} { eval hd_keywords { $name } } hd_puts {

SQL As Understood By SQLite

} 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 colum, 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.

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 permissable 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 indices and stores them in a special tables in the database where the query optimizer can use them to help make better index choices. If no arguments are given, all indices in all attached databases are analyzed. If a database name is given as the argument, all indices in that one database are analyzed. If the argument is a table name, then only indices associated with that one table are analyzed.

The initial implementation stores all statistics in a single table named sqlite_stat1. Future enhancements may create additional tables with the same name pattern except with the "1" changed to a different digit. The [DROP TABLE] command does not work on the sqlite_stat1 table, but all the content can be removed using the [DELETE] command, which has the same effect.

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

The ATTACH DATABASE statement adds another database file to the current database connection. If the filename contains punctuation characters it must be quoted. The database-names 'main' and 'temp' refer to the main database and the database used for temporary tables. These cannot be detached. Attached databases are removed using the [DETACH] statement.

You cannot create a new table with the same name as a table in an attached database, but you can attach a database which contains tables whose names are duplicates of tables in the main database. It is also permissible to attach the same database file multiple times.

Tables in an attached database can be referred to using the syntax database-name.table-name. If an attached table doesn't have a duplicate table name in the main database, it does not require a database-name prefix. When a database is attached, all of its tables which don't have duplicate names become the default table of that name. Any tables of that name attached afterwards require the database prefix. If the default table of a given name is detached, then the last table of that name attached becomes the new default.

Transactions involving multiple attached databases are atomic, assuming that the main database is not "[:memory:]". If the main database is ":memory:" 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 compile-time limit of [SQLITE_MAX_ATTACHED] attached database files.

############################################################################### 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. 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, you are guaranteed that no other thread or process 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, you are guaranteed that no other thread or process will be able to read or 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 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 cancelled, however.

The RELEASE is like a [COMMIT] for a SAVEPOINT. The RELEASE command causes all savepoints back to and including the first 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 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 tranaction 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

Transactions stack. 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 mark 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 aren't 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. They 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 comments can span any number of lines. 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 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 [SQLITE_MAX_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 ambiguious) and is the interpretation followed by PostgreSQL, MySQL, Firebird, and Oracle. Informix and Microsoft SQL Server follow the other interpretation of the standard.

The text of each CREATE INDEX statement is stored in the sqlite_master or sqlite_temp_master table, depending on whether the table being indexed is temporary. Every time the database is opened, all CREATE INDEX statements are read from the sqlite_master table and used to regenerate SQLite's internal representation of the index layout.

If the optional IF NOT EXISTS clause is present and another index with the same name aleady 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

A CREATE TABLE statement is basically the keywords "CREATE TABLE" followed by the name of a new table and a parenthesized list of column definitions and constraints. Tables names that begin with "sqlite_" are reserved for use by the engine.

Each column definition is the name of the column optionally followed by the [datatype] for that column, then one or more optional column constraints. SQLite uses [dynamic typing]; the datatype for the column does not restrict what data may be put in that column. The UNIQUE constraint causes an unique index to be created on the specified columns. All NULL values are considered different from each other and from all other values for the purpose of determining uniqueness, hence a UNIQUE column may contain multiple entries with the value of NULL. The COLLATE clause specifies what text [collating function] to use when comparing text entries for the column. The built-in [BINARY] collating function is used by default.

The DEFAULT constraint specifies a default value to use when doing an [INSERT]. The value may be NULL, a string constant or a number. The default value may also be one of the special case-independant keywords CURRENT_TIME, CURRENT_DATE or CURRENT_TIMESTAMP. If the value is NULL, a string constant or number, it is literally inserted into the column whenever an INSERT statement that does not specify a value for the column is executed. If the value is CURRENT_TIME, CURRENT_DATE or CURRENT_TIMESTAMP, then the current UTC date and/or time is inserted into the columns. For CURRENT_TIME, the format is HH:MM:SS. For CURRENT_DATE, YYYY-MM-DD. The format for CURRENT_TIMESTAMP is "YYYY-MM-DD HH:MM:SS".

The PRIMARY KEY attribute normally creates a UNIQUE index on the column or columns that are specified as the PRIMARY KEY. The only exception to this behavior is special [INTEGER PRIMARY KEY] column, described below. According to the SQL standard, PRIMARY KEY should imply NOT NULL. Unfortunately, due to a long-standing coding oversight, this is not the case in SQLite. 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.

SQLite uses [dynamic typing] instead of static typing. Except for the special case of [INTEGER PRIMARY KEY], SQLite will allow values of any type to be stored in any column regardless of the declared datatype of that column. The declared datatype is a [affinity | type affinity] that SQLite attempts to comply with, but the operation will proceed even if compliance is not possible.

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

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

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

CHECK constraints are supported as of [version 3.3.0]. Prior to version 3.3.0, CHECK constraints were parsed but not enforced.

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.

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

The text of each CREATE TABLE statement is stored in the sqlite_master table. Every time the database is opened, all CREATE TABLE statements are read from the sqlite_master table and used to regenerate SQLite's internal representation of the table layout. If the original command was a CREATE TABLE AS then then an equivalent CREATE TABLE statement is synthesized and store in sqlite_master in place of the original command. The text of CREATE TEMPORARY TABLE statements are stored in the sqlite_temp_master table.

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

Tables are removed using the DROP TABLE statement.

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 is unique within the same table. This integer is usually called the "rowid". The rowid is the actual key used in the B-Tree that implements an SQLite table. Rows are stored in rowid order. The rowid value can be accessed using one of the special names "ROWID", "OID", or "_ROWID_".

If a column is declared to be an INTEGER PRIMARY KEY, then that column is not a "real" database column but instead becomes an alias for the rowid. Unlike normal SQLite columns, the rowid must be a non-NULL integer value. The rowid is not able to hold floating point values, strings, BLOBs, or NULLs.

An INTEGER PRIMARY KEY column is an alias for the 64-bit signed integer rowid.

An INTEGER PRIMARY KEY column can also include the keyword [AUTOINCREMENT]. The [AUTOINCREMENT] keyword modified the way that B-Tree keys are automatically generated. Additional detail on automatic B-Tree key generation is available separately.

The special behavior of INTEGER PRIMARY KEY is only available if the type name is exactly "INTEGER" (in any mixture of upper and lower case.) 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 special behavior of INTEGER PRIMARY KEY is only available if the primary key is a single column. Multi-column primary keys do not become aliases for the rowid. The AUTOINCREMENT keyword only works on a column that is an alias for the rowid.

Note that searches against a rowid are generally about twice as fast as searches against any other PRIMARY KEY or indexed value.

Goofy behavior alert: The following three declarations all cause the column "x" be an alias for the rowid:

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

This asymmetrical behavior is unfortunate and is really due to a bug in the parser in early versions of SQLite. But fixing the bug would 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.

############################################################################## 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] of one or more specified columns of a table are updated.

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 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. Thereafter, 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'; }

Rowids and BEFORE triggers

Note that currently, triggers may behave oddly when created on tables with [INTEGER PRIMARY KEY] fields. If a BEFORE trigger program modifies the [INTEGER PRIMARY KEY] field of a row that will be subsequently updated by the statement that causes the trigger to fire, then the update may not occur. The workaround is to declare the table with a PRIMARY KEY column instead of an [INTEGER PRIMARY KEY] column.

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, unless the <database-name> is "temp". If no database name is specified, and the TEMP keyword is not present, the table 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. Virtual tables cannot be used in [sqlite3_enable_shared_cache | shared cache mode].

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 is used to remove records from a table. The command consists of the "DELETE FROM" keywords followed by the name of the table from which records are to be removed.

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

Restrictions on DELETE Statements Within CREATE TRIGGER

There are additional syntax restrictions on DELETE statements that occur within the body of a [CREATE TRIGGER] statement. The table-name must be unqualified. In other words, the database-name. prefix on the table name is not allowed within triggers. The table from which to delete must be in the same database as the table to which the trigger is attached.

The INDEXED BY and NOT INDEXED clauses are not allowed on DELETE statements within triggers.

The LIMIT clause (described below) is unsupported within triggers.

hd_fragment trucateopt {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 individual. 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.

Use Of LIMIT

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

The optional LIMIT clause can be used to limit the number of rows deleted, and thereby limit the size of the transaction. The ORDER BY clause is used only to determine which rows fall within the LIMIT. The order in which rows are deleted is arbitrary and is not determined by the ORDER BY clause.

The presence of a LIMIT clause defeats the truncate optimization causing all rows being deleted to be visited.

############################################################################### 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 named is completely removed from the disk. The only way to recover the index is to reenter the appropriate [CREATE INDEX] command.

The DROP INDEX statement does not reduce the size of the database file in the default mode. Empty space in the database is retained for later [INSERT] statements. To remove free space in the database, use the [VACUUM] command. If [auto_vacuum] mode is enabled for a database then space will be freed automatically by DROP INDEX.

############################################################################## 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. It 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 DROP TABLE statement does not reduce the size of the database file in the default mode. Empty space in the database is retained for later [INSERT] statements. To remove free space in the database, use the [VACUUM] statement. If [auto_vacuum] mode is enabled for a database then space will be freed automatically by DROP TABLE.

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

############################################################################## Section {DROP TRIGGER} droptrigger {{DROP TRIGGER}} BubbleDiagram drop-trigger-stmt 1

The DROP TRIGGER statement removes a trigger created by the [CREATE TRIGGER] statement. The trigger is deleted from the database schema. 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 name specified is the view name. It is removed from the database schema, but no actual data in the underlying base tables is modified.

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

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 about what indices would have been used.

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 behavior is undocumented, unspecified, and variable.

############################################################################## 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:

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

Supported unary prefix operators are these:

-    +    ~    NOT

The COLLATE operator can be thought of as a unary postfix operator. The COLLATE operator has the highest precedence. It always binds more tightly than any prefix unary operator or any binary operator.

hd_puts "

The unary operator [Operator +] is a no-op. It can be applied to strings, numbers, or blobs and it always gives as its result the value of 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 remainder of its left operand modulo its right operand.

The result of any binary operator is a numeric value, except for the [Operator ||] concatenation operator which gives a string result.

" 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. Scientific notation is supported for floating point literal values. 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

Parameters

A "variable" or "parameter" token specifies a placeholder in the expression for a literal 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 holds a spot for the next unused parameter.
:AAAA A colon followed by an identifier name holds a spot for a named parameter with the name AAAA. Named parameters are also numbered. The number assigned is the next unused number. To avoid confusion, it is best to avoid mixing named and numbered parameters.
@AAAA An "at" sign works exactly like a colon.
$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 occurances of "::" and a suffix enclosed in "(...)" containing any text at all. This syntax is the form of a variable name in the 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.

hd_fragment like LIKE ESCAPE

The LIKE and GLOB operators

The LIKE operator does a pattern matching comparison. The operand to the right contains the pattern, the left hand operand contains the string to match against the pattern. hd_puts "A percent symbol (\"%\") in the pattern matches any sequence of zero or more characters in the string. An underscore (\"_\") in the pattern matches any single character in the string. Any other character matches itself or it's lower/upper case equivalent (i.e. case-insensitive matching). (A bug: SQLite only understands upper/lower case for ASCII characters. The LIKE operator is case sensitive 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 itself matches a literal percent symbol, underscore or escape character in the string, 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 user-defined 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() user function. The default match() function implementation raises and 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 equivalent to a pair of comparisons. "a BETWEEN b AND c" is equivalent to "a>=b AND a<=c". The precedence of the BETWEEN operator is the same as the precedence as operators == and != and LIKE and groups left to right.

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. Row keys act like read-only columns. A row key can be used anywhere a regular column can be used, except that you cannot change the value of a row key in an [UPDATE] or [INSERT] statement. "SELECT * ..." does not return the row key.

Subqueries

[SELECT] statements can appear in expressions as either the right-hand operand of the IN operator, as a scalar quantity, or as the operand of an EXISTS operator. As a scalar quantity or the operand of an IN operator, the SELECT should have only a single column in its result. Compound SELECTs (connected with keywords like UNION or EXCEPT) are allowed. With the EXISTS operator, the columns in the result set of the [SELECT] are ignored and the expression returns TRUE if one or more rows exist and FALSE if the result set is empty. If no terms in the [SELECT] expression refer to value in the containing query, then the expression is evaluated once prior to any other processing and the result is reused as necessary. If the [SELECT] expression does contain variables from the outer query, then the [SELECT] is reevaluated every time it is needed.

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

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

CAST expressions

A CAST expression changes the [datatype] of the into the type specified by <type>. <type> can be any non-empty type name that is valid for the type in a column definition of a [CREATE TABLE] statement.

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 "$syntax" hd_puts {} if {[llength $keywords]==0} { regexp {[a-z_]+} $syntax name hd_fragment $name $name } else { eval hd_fragment $keywords hd_keywords $keywords } 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)} {} { Return the absolute value of the numeric argument X. Return NULL if X is NULL. Return 0.0 if X is not a numeric value. } funcdef {changes()} {} { Return the number of database rows that were changed or inserted or deleted by the most recently complete SQL. This is a wrapper around the [sqlite3_changes()] C/C++ function. } funcdef {coalesce(X,Y,...)} {} { Return a copy of the first non-NULL argument. If all arguments are NULL then NULL is returned. There must be at least 2 arguments. } funcdef {glob(X,Y)} {} { This function is used to implement the "Y GLOB X" syntax of SQLite. Note that the X and Y arguments are reversed in the glob() function relative to the infix [GLOB] operator. The [sqlite3_create_function()] interface can be used to override this function and thereby change the operation of the [GLOB] operator. } funcdef {ifnull(X,Y)} {} { Return a copy of the first non-NULL argument. If both arguments are NULL then NULL is returned. The ifnull() functions and [coalesce()] with two arguments are interchangeable. } funcdef {hex(X)} {} { The argument is interpreted as a BLOB. The result is a hexadecimal rendering of the content of that blob. } funcdef {last_insert_rowid()} {} { Return the [ROWID] of the last row insert from this connection to the database. This is the same value that would be returned from the [sqlite3_last_insert_rowid()] API function. } funcdef {length(X)} {} { Return the string length of X in characters if X is a string, or in bytes if X is a blob. } funcdef {like(X,Y) like(X,Y,Z)} {} { This function is used to implement the "Y LIKE X [ESCAPE Z]" syntax of SQL. If the optional ESCAPE clause is present, then the user-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 this function and thereby change the operation of the [LIKE] operator. When doing this, 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)} {load_extension} { Load SQLite extensions out of the shared library file named X using the entry point Y. The result is a NULL. If Y is omitted then the default entry point of sqlite3_extension_init is used. This function raises an exception if the extension fails to load or initialize correctly.

This 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)} {} { Return 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)} {} { Return 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, spaces are removed. } funcdef {max(X,Y,...)} {maxCoreFunc max} { Return the argument with the maximum value. Or return NULL if any argument is NULL. Note that max() is a simple function when it has 2 or more arguments but converts to an aggregate function if given only a single argument. } funcdef {min(X,Y,...)} {minCoreFunc min} { Return the argument with the minimum value. Note that min() is a simple function when it has 2 or more arguments but converts to an aggregate function if given only a single argument. } funcdef {nullif(X,Y)} {} { Return the first argument if the arguments are different, otherwise return NULL. } funcdef {quote(X)} {} { This routine 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. SQLite uses this function internally in its implementation of [VACUUM] so if this function is overloading to provide incompatible behavior, the [VACUUM] command will likely cease to work. } funcdef {random()} {} { Return a pseudo-random integer between -9223372036854775808 and +9223372036854775807. } funcdef {randomblob(N)} {} { Return an N-byte blob containing pseudo-random bytes. N should be a postive integer.

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)} {} { Return a string formed by substituting string Z for every occurrance of string Y in string X. The [BINARY] collating sequence is used for comparisons. If Y is an empty string then return X unchanged. } funcdef {round(X) round(X,Y)} {} { Round off the number X to Y digits to the right of the decimal point. If the Y argument is omitted, 0 is assumed. } funcdef {rtrim(X) rtrim(X,Y)} {} { Return 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, spaces are removed. } funcdef {soundex(X)} {} { Compute the soundex encoding of the string X. The string "?000" is returned if the argument is NULL. This function is omitted from SQLite by default. It is only available the -DSQLITE_SOUNDEX=1 compiler option is used when SQLite is built. } funcdef {sqlite_version()} {sqlite_version} { Return the version string for the SQLite library that is running. Example: "3.5.9" } funcdef {substr(X,Y,Z) substr(X,Y)} {} { Return a substring of input string X that begins with the Y-th character and which is Z characters long. If Z is omitted then all character through the end of the string are returned. The left-most character of X is number 1. If Y is negative the the first character of the substring is found by counting from the right rather than the left. If X is string then characters indices refer to actual UTF-8 characters. If X is a BLOB then the indices refer to bytes. } funcdef {total_changes()} {} { Return 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)} {} { Return a string formed by removing any and all characters that appear in Y from both ends of X. If the Y argument is omitted, spaces are removed. } funcdef {typeof(X)} {} { Return the [datatype] of the expression X. The only return values are "null", "integer", "real", "text", and "blob". } funcdef {upper(X)} {} { Return a copy of input string X converted to all upper-case letters. The implementation of this function uses the C library routine toupper() which means it may not work correctly on non-ASCII UTF-8 strings. } funcdef {zeroblob(N)} {} { Return 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}

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 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() 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 Julian day - number of days since noon in Greenwich on November 24, 4714 B.C. (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 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 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. Universal Coordinated Time (UTC) is used. Format 12 is the Julian day number expressed as a floating point value.

Modifiers

The time string can be followed by zero or more modifiers that alter the date and time string. Each modifier is a transformation that is applied to the time string 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 specified by the preceding timestring. 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 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.

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

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.

Date computations do not give correct results for dates before Julian day number 0 (-4713-11-24 12:00:00).

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 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)} {} { Return 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() NULL if and only if there are no non-NULL inputs. } funcdef {count(X) count(*)} {} { The first form return a count of the number of times that X is not NULL in a group. The second form (with no argument) returns the total number of rows in the group. } funcdef {group_concat(X) group_concat(X,Y)} {} { The result is a string which is the concatenation of all non-NULL values of X. If parameter Y is 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} { Return 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. NULL is returned if and only if there are no non-NULL values in the group. } funcdef {min(X)} {minAggFunc agg_min} { Return 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. NULL is only returned if and only if there are no non-NULL values in the group. } funcdef {sum(X) total(X)} {sumFunc sum total} { Return the numeric 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 and integer overflow. }

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

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

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

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

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. Likely, the "DEFAULT VALUES" form of the INSERT statement is support 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", to make the syntax seem more natural. 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 specifies an algorithm used to resolve constraint conflicts. There are five choices: ROLLBACK, ABORT, FAIL, IGNORE, and REPLACE. The default algorithm is ABORT. This is what they mean:

ROLLBACK

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

ABORT

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

FAIL

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

IGNORE

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

REPLACE

When a UNIQUE constraint violation occurs, the pre-existing rows that are causing the constraint violation are removed prior to inserting or updating the current row. Thus the insert or update always occurs. The command continues executing normally. No error is returned. If a NOT NULL constraint violation occurs, the NULL value is replaced by the default value for that column. If the column has no default value, then the ABORT algorithm is used. If a CHECK constraint violation occurs then the IGNORE algorithm is used.

When this conflict resolution strategy deletes rows in order to satisfy a constraint, it does not invoke [CREATE TRIGGER | delete triggers] on those rows. Nor is the [sqlite3_update_hook | update hook] invoked. 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.

In the first form, all indices in all attached databases that use the named collation sequence are recreated. In the second form, if [database-name.]table/index-name identifies a table, then all indices associated with the table are rebuilt. If an index is identified, then only this specific index is deleted and recreated.

If no database-name is specified and there exists both a table or index and a collation sequence of the specified name, then indices associated with the collation sequence only are reconstructed. This ambiguity may be dispelled 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 "INSERT OR REPLACE" variant of the INSERT command. This alias is provided for compatibility with MySQL. See the INSERT command documentation for additional information.

############################################################################### Section SELECT select {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 number of columns in the result is specified by the expression list in between the SELECT and FROM keywords. Any arbitrary expression can be used as a result. If a result expression is } hd_puts "[Operator *] then all columns of all tables are substituted\n" hd_puts "for that one expression. If the expression is the name of\n" hd_puts "a table followed by [Operator .*] then the result is all columns\n" hd_puts {in that one table.

The DISTINCT keyword causes a subset of result rows to be returned, in which each result row is different. NULL values are not treated as distinct from each other. The default behavior is that all result rows be returned, which can be made explicit with the keyword ALL.

The query is executed against one or more tables specified after the FROM keyword. If multiple tables names are separated by commas, then the query is against the cross join of the various tables. The full SQL-92 join syntax can also be used to specify joins. A sub-query in parentheses may be substituted for any table name in the FROM clause. The entire FROM clause may be omitted, in which case the result is a single row consisting of the values of the expression list.

The WHERE clause can be used to limit the number of rows over which the query operates.

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

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

Each term of an ORDER BY expression is processed as follows:

  1. If the ORDER BY expression is a constant integer K then the output is ordered by the K-th column of the result set.

  2. If the ORDER BY expression is an identifier and one of the output columns has an alias by the same name, then the output is ordered by the identified column.

  3. Otherwise, the ORDER BY expression is evaluated and the output is ordered by the value of that expression.

In a compound SELECT statement, the third ORDER BY matching rule requires that the expression be identical to one of the columns in the result set. The three rules are first applied to the left-most SELECT in the compound. If a match is found, the search stops. Otherwise, the next SELECT to the right is tried. This continues until a match is found. Each term of the ORDER BY clause is processed separately and may come from different SELECT statements in the compound.

The LIMIT clause places an upper bound on the number of rows returned in the result. A negative LIMIT indicates no upper bound. The optional OFFSET following LIMIT specifies how many rows to skip at the beginning of the result set. In a compound query, the LIMIT clause may only appear on the final SELECT statement. The limit is applied to the entire query not to the individual SELECT statement to which it is attached. Note that if the OFFSET keyword is used in the LIMIT clause, then the limit is the first number and the offset is the second number. If a comma is used instead of the OFFSET keyword, then the offset is the first number and the limit is the second number. This seeming contradition is intentional - it maximizes compatibility with legacy SQL database systems.

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

############################################################################## Section UPDATE update {UPDATE UPDATEs} BubbleDiagram update-stmt 1 BubbleDiagram qualified-table-name

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

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

Restrictions on UPDATE Statements Within CREATE TRIGGER

There are additional syntax restrictions on UPDATE statements that occur within the body of a [CREATE TRIGGER] statement. The table-name must be unqualified. In other words, the database-name. prefix on the table name is not allowed within triggers. The table to be modified must be in the same database as the table to which the trigger is attached.

The INDEXED BY and NOT INDEXED clauses are not allowed on UPDATE statements within triggers.

The LIMIT clause (described below) is unsupported within triggers.

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

The optional LIMIT clause can be used to limit the number of rows modifed, and thereby limit the size of the transaction. The ORDER BY clause is used only to determine which rows fall within the LIMIT. The order in which rows are modified is arbitrary and is not determined by the ORDER BY clause.

############################################################################## Section VACUUM vacuum VACUUM BubbleDiagram vacuum-stmt 1

When an object (table, index, or trigger) is dropped from the database, it leaves behind empty space. This empty space will be reused the next time new information is added to the database. But in the meantime, the database file might be larger than strictly necessary. Also, frequent inserts, updates, and deletes can cause the information in the database to become fragmented - scrattered out all across the database file rather than clustered together in one place.

The VACUUM command cleans the main database by copying its contents to a temporary database file and reloading the original database file from the copy. This eliminates free pages, aligns table data to be contiguous, and otherwise cleans up the database file structure.

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

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

The VACUUM command will fail if there is an active transaction. The VACUUM command is a no-op for in-memory databases.

As of SQLite version 3.1, an alternative to using the VACUUM command is auto-vacuum mode, enabled using the [auto_vacuum] pragma. When [auto_vacuum] is enabled for a database, large deletes cause the size of the database file to shrink. However, [auto_vacuum] also causes excess fragmentation of the database file. And [auto_vacuum] does not compact partially filled pages of the database as VACUUM does.

The [page_size] and/or [auto_vacuum] mode of a database can be changed by invoking the [page_size pragma] and/or [auto_vacuum pragma] and then immediately VACUUMing the database.

############################################################################## 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 preformance 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* 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 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 is extended to allow many keywords to be used unquoted as the names of databases, tables, indices, triggers, views, columns, user-defined functions, collations, attached databases, and virtual function modules. In the list of keywords that follows, those that can be used as identifiers are shown in an italic font. Keywords that must be quoted in order to be used as identifiers are shown in bold.

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 following are the keywords currently recognized by SQLite:

set n [llength $keyword_list] set nCol 5 set nRow [expr {($n+$nCol-1)/$nCol}] set i 0 foreach word $keyword_list { if {[string index $word end]=="*"} { set word [string range $word 0 end-1] set font i } else { set font b } if {$i==$nRow} { hd_puts "" set i 1 } else { incr i } hd_puts "<$font>$word
" }

Special names

The following are not keywords in SQLite, but are used as names of system objects. They can be used as an identifier for a different type of object.

_ROWID_
MAIN
OID
ROWID
SQLITE_MASTER
SQLITE_SEQUENCE
SQLITE_TEMP_MASTER
TEMP