Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Add requirements markings and a section on the CASE expression to the SQL language documentation. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA1: |
ac0c9ef1a2aa8e77392c5bb94d4456f0 |
User & Date: | drh 2009-12-12 01:14:22.000 |
Context
2009-12-12
| ||
15:32 | Fix some requirements markings. Changes the evidence scanner to understand that requirement text that begins with "--" is comment, not actual requirement text. (check-in: 88da6668cb user: drh tags: trunk) | |
01:14 | Add requirements markings and a section on the CASE expression to the SQL language documentation. (check-in: ac0c9ef1a2 user: drh tags: trunk) | |
2009-12-11
| ||
16:54 | Remove the old-style requirements documents from the set of documentation pages generated. (check-in: f259e08f31 user: drh tags: trunk) | |
Changes
Changes to pages/lang.in.
1 2 3 4 5 6 7 8 9 | <title>Query Language Understood by SQLite</title> <h1 align=center>SQL As Understood By SQLite</h1> <p>SQLite understands most of the standard SQL language. But it does <a href="omitted.html">omit some features</a> 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 | | | < < < < < < < < < | 1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 | <title>Query Language Understood by SQLite</title> <h1 align=center>SQL As Understood By SQLite</h1> <p>SQLite understands most of the standard SQL language. But it does <a href="omitted.html">omit some features</a> while at the same time adding a few features of its own. This document attempts to describe precisely what parts of the SQL language SQLite does and does not support. A list of [SQL keywords] is also provided. The SQL language syntax is described by [syntax diagrams]. <p>The following syntax documentation topics are available:</p> <table width="100%" cellpadding="5" border="0"> <tr><td valign="top"><ul> <tcl> |
︙ | ︙ | |||
81 82 83 84 85 86 87 | if {$i==$lang_section_break || $i==2*$lang_section_break} { hd_puts "</ul></td><td valign=\"top\"><ul>" } } </tcl> </ul></td></tr></table> | | | 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 | if {$i==$lang_section_break || $i==2*$lang_section_break} { hd_puts "</ul></td><td valign=\"top\"><ul>" } } </tcl> </ul></td></tr></table> <p>^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.</p> <tcl>BubbleDiagram sql-stmt-list</tcl> <p>Each SQL statement in the statement list is an instance of the |
︙ | ︙ | |||
133 134 135 136 137 138 139 | <p>SQLite supports a limited subset of ALTER TABLE. The ALTER TABLE command in SQLite allows the user to rename a table or to add a new column to an existing table. It is not possible to rename a column, remove a column, or add or remove constraints from a table. </p> | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | > | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 | <p>SQLite supports a limited subset of ALTER TABLE. The ALTER TABLE command in SQLite allows the user to rename a table or to add a new column to an existing table. It is not possible to rename a column, remove a column, or add or remove constraints from a table. </p> <p> ^(The RENAME TO syntax is used to rename the table identified by <i>[database-name.]table-name</i> to <i>new-table-name</i>.)^ This command cannot be used to move a table between attached databases, only to rename a table within the same database.</p> <p> ^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. </p> <p>^If [foreign key constraints] are [foreign_keys pragma | enabled] when a table is renamed, then any [foreign-key-clause | REFERENCES clauses] in any table (either the table being renamed or some other table) that refer to the table being renamed are modified to refer to the renamed table by its new name. <p> ^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: <ul> <li>The column may not have a PRIMARY KEY or UNIQUE constraint.</li> <li>The column may not have a default value of CURRENT_TIME, CURRENT_DATE or CURRENT_TIMESTAMP.</li> <li>If a NOT NULL constraint is specified, then the column must have a default value other than NULL. <li>^If [foreign key constraints] are [foreign_keys pragma | enabled] and a column with a [foreign-key-clause | REFERENCES clause] is added, the column must have a default value of NULL. </ul>)^ <p>^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.</p> <p> ^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. </p> <p>After ADD COLUMN has been run on a database, that database will not be readable by SQLite version 3.1.3 and earlier.</p> <tcl> ############################################################################## Section {ANALYZE} analyze ANALYZE BubbleDiagram analyze-stmt 1 </tcl> <p> ^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.</p> <p> ^The default implementation stores all statistics in a single table named <b>sqlite_stat1</b>. ^If SQLite is compiled with the [SQLITE_ENABLE_STAT2] option, then additional histogram data is collected and stored in <b>sqlite_stat2</b>. Future enhancements may create additional tables with the same name pattern except with the "1" or "2" changed to a different digit.</p> <p> ^The [DROP TABLE] command does not work on the <b>sqlite_stat1</b> or <b>sqlite_stat2</b> tables, but all the content of those tables can be queried using [SELECT] and can be deleted, augmented, or modified using the [DELETE], [INSERT], and [UPDATE] commands. Appropriate care should be used when changing the content of the statistics tables as invalid content can cause SQLite to select inefficient query plans. Generally speaking, one should not modify the content of the statistics tables by any mechanism other than invoking the ANALYZE command.</p> <p> ^Statistics gathered by ANALYZE are <u>not</u> automatically updated as the content of the database changes. If the content of the database changes significantly, or if the database schema changes, then one should consider rerunning the ANALYZE command in order to update the statistics.</p> <tcl> ############################################################################## Section {ATTACH DATABASE} attach *ATTACH BubbleDiagram attach-stmt 1 </tcl> <p> ^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.</p> <p> ^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. ^If the system is not running in [shared cache mode], it is also permissible to attach the same database file multiple times.</p> <p> ^(Tables in an attached database can be referred to using the syntax <i>database-name.table-name</i>.)^ ^If an attached table doesn't have a duplicate table name in the main database, it does not require a <i>database-name</i> 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.</p> <p> ^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. </p> <p> ^There is a compile-time limit of [SQLITE_MAX_ATTACHED] attached database files.</p> <tcl> ############################################################################### Section {BEGIN TRANSACTION} transaction {*BEGIN COMMIT ROLLBACK} BubbleDiagram begin-stmt BubbleDiagram commit-stmt BubbleDiagram rollback-stmt </tcl> <p> ^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. </p> <p> ^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. </p> <p> ^END TRANSACTION is an alias for COMMIT. </p> <p> ^(Transactions created using BEGIN...COMMIT do not nest.)^ ^For nested transactions, use the [SAVEPOINT] and [RELEASE] commands. The "TO SAVEPOINT <i>name</i>" 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.</p> <p> ^Transactions can be deferred, immediate, or exclusive. ^The default transaction behavior is deferred. ^Deferred means that no locks are acquired on the database until the database is first accessed. ^Thus with a deferred transaction, the BEGIN statement itself does nothing to the filesystem. ^Locks are not acquired until the first read or write operation. ^The first read operation against a database creates a [SHARED] lock and the first write operation creates a [RESERVED] lock. ^Because the acquisition of locks is deferred until they are needed, it is possible that another thread or process could create a separate transaction and write to the database after the BEGIN on the current thread has executed. ^If the transaction is immediate, then [RESERVED] locks are acquired on all databases as soon as the BEGIN command is executed, without waiting for the database to be used. ^After a BEGIN IMMEDIATE, 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. </p> <p> ^(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].)^ </p> <p> ^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]. </p> <p> ^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. </p> <p> ^The ROLLBACK will fail with an error code [SQLITE_BUSY] if there are any pending queries. ^Both read-only and read/write queries will cause a ROLLBACK to fail. A ROLLBACK must fail if there are pending read operations (unlike COMMIT which can succeed) because bad things will happen if the in-memory image of the database is changed out from under an active query. </p> <p> If [PRAGMA journal_mode] is set to OFF (thus disabling the rollback journal file) then the behavior of the ROLLBACK command is undefined. </p> <h3>Response To Errors Within A Transaction</h3> <p> ^(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:</p> <ul> <li> [SQLITE_FULL]: database or disk full <li> [SQLITE_IOERR]: disk I/O error <li> [SQLITE_BUSY]: database in use by another process <li> [SQLITE_NOMEM]: out or memory <li> [SQLITE_INTERRUPT]: processing [sqlite3_interrupt|interrupted] by application request </ul>)^ <p> ^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.</p> <p>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.</p> <p>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.</p> <tcl> ############################################################################### Section {SAVEPOINT} savepoint {SAVEPOINT RELEASE} BubbleDiagram savepoint-stmt BubbleDiagram release-stmt BubbleDiagram rollback-stmt </tcl> <p> ^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.</p> <p> ^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.)^</p> <p>^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.</p> <p>^The RELEASE command is like a [COMMIT] for a SAVEPOINT. ^The RELEASE command causes all savepoints back to and including the most recent savepoint with a matching name to be removed from the transaction stack. ^The RELEASE of an inner transaction does not cause any changes to be written to the database file; it merely removes savepoints from the transaction stack such that it is no longer possible to ROLLBACK TO those savepoints. ^If a RELEASE command releases the outermost savepoint, so that the transaction stack becomes empty, then RELEASE is the same as [COMMIT]. ^The [COMMIT] command may be used to release all savepoints and commit the transaction even if the transaction was originally started by a SAVEPOINT command instead of a [BEGIN] command.</p> <p>^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.</p> <p>^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.</p> <p>There are several ways of thinking about the RELEASE command:</p> <ul> <li><p> Some people view RELEASE as the equivalent of COMMIT for a SAVEPOINT. |
︙ | ︙ | |||
495 496 497 498 499 500 501 | </p></li> </ul> <h3>Transaction Nesting Rules</h3> | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | > | | | | | | | < | | | > | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | < | | | | | > | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 784 785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907 908 909 910 911 912 913 914 915 916 917 918 919 920 | </p></li> </ul> <h3>Transaction Nesting Rules</h3> <p>^The last transaction started will be the first transaction committed or rolled back.</p> <p>^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.</p> <p>^The [COMMIT] command commits all outstanding transactions and leaves the transaction stack empty.</p> <p>^The RELEASE command starts with the most recent addition to the transaction stack and releases savepoints backwards in time until it releases a savepoint with a matching savepoint-name. ^Prior savepoints, even savepoints with matching savepoint-names, are unchanged. ^If the RELEASE command causes the transaction stack to become empty (if the RELEASE command releases the outermost transaction from the stack) then the transaction commits.</p> <p>^The [ROLLBACK] command without a TO clause rolls backs all transactions and leaves the transaction stack empty.</p> <p>^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.</p> <tcl> ############################################################################### Section comment comment {comment *comments} BubbleDiagram comment-syntax </tcl> <p>Comments are not SQL commands, but can occur within the text of SQL queries passed to [sqlite3_prepare_v2()] and related interfaces.. ^Comments are treated as whitespace by the parser. ^Comments can begin anywhere whitespace can be found, including inside expressions that span multiple lines. </p> <p>^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.</p> <p>^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. </p> <p>^Comments can appear anywhere whitespace can occur, including inside expressions and in the middle of other SQL statements. ^Comments do not nest. </p> <tcl> ############################################################################## Section {CREATE INDEX} createindex {{CREATE INDEX}} BubbleDiagram create-index-stmt 1 BubbleDiagram indexed-column </tcl> <p>^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.</p> <p>^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.</p> <p>^The COLLATE clause optionally following each column name defines a collating sequence used for text entries in that column. ^The default collating sequence is the collating sequence defined for that column in the [CREATE TABLE] statement. ^Or if no collating sequence is otherwise defined, the built-in BINARY collating sequence is used.</p> <p>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].</p> <p>^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.</p> <p>^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.</p> <p>^Indexes are removed with the [DROP INDEX] command.</p> <tcl> ############################################################################## 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 </tcl> <p>^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 "<b>sqlite_</b>" are reserved for use by SQLite itself and cannot normally appear in a CREATE TABLE statement.</p> <p>^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. <p> ^The DEFAULT constraint specifies a default value to use when doing an [INSERT]. ^The value may be NULL, a string constant, a number, or a constant expression enclosed in parentheses. ^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 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". </p> <p>^(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.</p> <p>^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.</p> <p>^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.</p> <p> ^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.</p> <p>^The optional [conflict clause] following each constraint allows the specification of an alternative default constraint conflict resolution algorithm for that constraint. ^If no conflict clause is specified, the ABORT algorithm is used. ^Different constraints within the same table may have different conflict resolution algorithms. ^If an [INSERT] or [UPDATE] statement specifies a conflict resolution algorithm, then the algorithm specified on the INSERT or UPDATE statement overrides the algorithm specified in the CREATE TABLE statement. See the section titled [ON CONFLICT] for additional information.</p> <p>CHECK constraints are supported as of [version 3.3.0]. Prior to version 3.3.0, CHECK constraints were parsed but not enforced.</p> <p>^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.</p> <p>^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.</p> <p>^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.</p> <p>^Tables are removed using the [DROP TABLE] statement. </p> <tcl>hd_fragment rowid {INTEGER PRIMARY KEY} ROWID rowid</tcl> <h3>ROWIDs and the INTEGER PRIMARY KEY</h3> <p>^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 "<b>ROWID</b>", "<b>OID</b>", or "<b>_ROWID_</b>" assuming those names are no used by other conventional table columns.</p> <p> ^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.</p> <blockquote><i> ^An INTEGER PRIMARY KEY column is an alias for the 64-bit signed integer rowid. </i></blockquote> <p>^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 <a href="autoinc.html">separately</a>.</p> <p>^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.</p> <p>Note that searches against a rowid are generally about twice as fast as searches against any other PRIMARY KEY or indexed value. </p> <p><b>Goofy behavior alert:</b> ^(The following three declarations all cause the column "x" be an alias for the rowid:</p> <ul> <li><tt>CREATE TABLE t(x INTEGER PRIMARY KEY ASC, y, z);</tt> <li><tt>CREATE TABLE t(x INTEGER, y, z, PRIMARY KEY(x ASC));</tt> <li><tt>CREATE TABLE t(x INTEGER, y, z, PRIMARY KEY(x DESC));</tt> </ul>)^ <p>But, in contrast, ^(the following declaration does <u>not</u> result in "x" being an alias for the rowid:</p> <ul> <li><tt>CREATE TABLE t(x INTEGER PRIMARY KEY DESC, y, z);</tt> </ul>)^ <p>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.</p> <tcl> ############################################################################## Section {CREATE TRIGGER} createtrigger {{CREATE TRIGGER}} BubbleDiagram create-trigger-stmt 1 </tcl> <p>^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. </p> <p>^A trigger may be specified to fire whenever a [DELETE], [INSERT], or [UPDATE] of a particular database table occurs, or whenever an [UPDATE] occurs on on one or more specified columns of a table.</p> <p>^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.</p> <p>^(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.<i>column-name</i>" and "OLD.<i>column-name</i>", where <i>column-name</i> 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:</p> <table border=0 cellpadding=10> <tr> <td valign="top" align="right" width=120><i>INSERT</i></td> <td valign="top">NEW references are valid</td> </tr> <tr> <td valign="top" align="right" width=120><i>UPDATE</i></td> <td valign="top">NEW and OLD references are valid</td> </tr> <tr> <td valign="top" align="right" width=120><i>DELETE</i></td> <td valign="top">OLD references are valid</td> </tr> </table> </p>)^ <p>^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.</p> <p>^The BEFORE or AFTER keyword determines when the trigger actions will be executed relative to the insertion, modification or removal of the associated row.</p> <p>^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.</p> <p>^Triggers are automatically [DROP TRIGGER | dropped] when the table that they are associated with (the <i>table-name</i> 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].</p> <p>^Triggers are removed using the [DROP TRIGGER] statement.</p> <h3>Syntax Restrictions On UPDATE, DELETE, and INSERT Statements Within Triggers</h3> <p>^The [UPDATE], [DELETE], and [INSERT] statements within triggers do not support the full syntax for [UPDATE], [DELETE], and [INSERT] statements. The following restrictions apply:</p> <ul> <li><p> ^(The name of the table to be modified in an [UPDATE], [DELETE], or [INSERT] statement must be an unqualified table name. In other words, one must use just "<i>tablename</i>" not "<i>database</i><b>.</b><i>tablename</i>" when specifying the table.)^ ^The table to be modified must exist in the same database as the table or view to which the trigger is attached. </p></li> <li><p> ^The "INSERT INTO <i>table</i> DEFAULT VALUES" form of the [INSERT] statement is not supported. </p></li> <li><p> ^The INDEXED BY and NOT INDEXED clauses are not supported for [UPDATE] and [DELETE] statements. </p></li> <li><p> ^(The ORDER BY and LIMIT clauses on [UPDATE] and [DELETE] statements are not supported. ORDER BY and LIMIT are not normally supported for [UPDATE] or [DELETE] in any context but can be enabled for top-level statements using the [SQLITE_ENABLE_UPDATE_DELETE_LIMIT] compile-time option. However, that compile-time option only applies to top-level [UPDATE] and [DELETE] statements, not [UPDATE] and [DELETE] statements within triggers.)^ </p></li> </ul> <tcl>hd_fragment instead_of_trigger {INSTEAD OF} {INSTEAD OF trigger}</tcl> <h3>INSTEAD OF trigger</h3> <p>^Triggers may be created on [views], as well as ordinary tables, by specifying INSTEAD OF in the CREATE TRIGGER statement. ^If one or more ON INSERT, ON DELETE or ON UPDATE triggers are defined on a view, then it is not an error to execute an INSERT, DELETE or UPDATE statement on the view, respectively. ^Instead, executing an INSERT, DELETE or UPDATE on the view causes the associated triggers to fire. ^The real tables underlying the view are not modified (except possibly explicitly, by a trigger program).</p> <p>^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.</p> <h3>Examples</h3> <p>^(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:</p> <tcl>Example { CREATE TRIGGER update_customer_address UPDATE OF address ON customers BEGIN |
︙ | ︙ | |||
935 936 937 938 939 940 941 | UPDATE customers SET address = '1 Main St.' WHERE name = 'Jack Jones'; }</tcl> <p>causes the following to be automatically executed:</p> <tcl>Example { UPDATE orders SET address = '1 Main St.' WHERE customer_name = 'Jack Jones'; | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | > | | | | | | | | | > | | | | | | > | | | | | | 928 929 930 931 932 933 934 935 936 937 938 939 940 941 942 943 944 945 946 947 948 949 950 951 952 953 954 955 956 957 958 959 960 961 962 963 964 965 966 967 968 969 970 971 972 973 974 975 976 977 978 979 980 981 982 983 984 985 986 987 988 989 990 991 992 993 994 995 996 997 998 999 1000 1001 1002 1003 1004 1005 1006 1007 1008 1009 1010 1011 1012 1013 1014 1015 1016 1017 1018 1019 1020 1021 1022 1023 1024 1025 1026 1027 1028 1029 1030 1031 1032 1033 1034 1035 1036 1037 1038 1039 1040 1041 1042 1043 1044 1045 1046 1047 1048 1049 1050 1051 1052 1053 1054 1055 1056 1057 1058 1059 1060 1061 1062 1063 1064 1065 1066 1067 1068 1069 1070 1071 1072 1073 1074 1075 1076 1077 1078 1079 1080 1081 1082 1083 1084 1085 1086 1087 1088 1089 1090 1091 1092 1093 1094 1095 1096 1097 1098 1099 1100 1101 1102 1103 1104 1105 1106 1107 1108 1109 1110 1111 1112 1113 1114 1115 1116 1117 1118 1119 1120 1121 1122 1123 1124 1125 1126 1127 1128 1129 1130 1131 1132 1133 1134 1135 1136 1137 1138 1139 1140 1141 1142 1143 1144 1145 1146 1147 1148 1149 1150 1151 1152 1153 1154 1155 1156 1157 1158 1159 1160 1161 1162 1163 1164 1165 1166 1167 1168 1169 1170 1171 1172 1173 1174 1175 1176 1177 1178 1179 1180 1181 | UPDATE customers SET address = '1 Main St.' WHERE name = 'Jack Jones'; }</tcl> <p>causes the following to be automatically executed:</p> <tcl>Example { UPDATE orders SET address = '1 Main St.' WHERE customer_name = 'Jack Jones'; }</tcl>)^ <tcl>hd_fragment undef_before {undefined BEFORE trigger behavior}</tcl> <h3>Cautions On The Use Of BEFORE triggers</h3> <p>If a BEFORE UPDATE or BEFORE DELETE trigger modifies or deletes a row that was to have been updated or deleted, then the result of the subsequent update or delete operation is undefined. Furthermore, if a BEFORE trigger modifies or deletes a row, then it is undefined whether or not AFTER triggers that would have otherwise run on those rows will in fact run. </p> <p>The value of NEW.rowid is undefined in a BEFORE INSERT trigger in which the rowid is not explicitly set to an integer.</p> <p>Because of the behaviors described above, programmers are encouraged to prefer AFTER triggers over BEFORE triggers.</p> <h3>The RAISE() function</h3> <p>^(A special SQL function RAISE() may be used within a trigger-program,)^ with the following syntax</p> <tcl>BubbleDiagram raise-function</tcl> <p>^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.</p> <p>^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. </p> <tcl> ############################################################################### Section {CREATE VIEW} {createview} {{CREATE VIEW} view *views} BubbleDiagram create-view-stmt 1 </tcl> <p>^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. </p> <p>^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.</p> <p> ^If a <database-name> is specified, then the view is created in the named database. ^It is an error to specify both a <database-name> and the TEMP keyword on a VIEW, unless the <database-name> is "temp". ^If no database name is specified, and the TEMP keyword is not present, the VIEW is created in the main database.</p> <p>^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.</p> <tcl> ############################################################################## Section {CREATE VIRTUAL TABLE} {createvtab} {{CREATE VIRTUAL TABLE}} BubbleDiagram create-virtual-table-stmt 1 </tcl> <p>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.</p> <p>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.</p> <p>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.</p> <p>^A virtual table is destroyed using the ordinary [DROP TABLE] statement. There is no DROP VIRTUAL TABLE statement.</p> <tcl> ############################################################################## Section DELETE delete {DELETE *DELETEs} BubbleDiagram delete-stmt 1 BubbleDiagram qualified-table-name </tcl> <p>^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. </p> <p>^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.</p> <h3>Restrictions on DELETE Statements Within CREATE TRIGGER</h3> <p>^There are additional syntax restrictions on DELETE statements that occur within the body of a [CREATE TRIGGER] statement. ^The <i>table-name</i> must be unqualified. ^(In other words, the <i>database-name</i><b>.</b> 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.</p> <p>^The INDEXED BY and NOT INDEXED clauses are not allowed on DELETE statements within triggers.</p> <p>^The LIMIT clause (described below) is unsupported within triggers.</p> <tcl>hd_fragment trucateopt {truncate optimization}</tcl> <h3>The Truncate Optimization</h3> <p>^When the WHERE is omitted from a DELETE statement and the table being deleted has no triggers, SQLite uses an optimization to erase the entire table content without having to visit each row of the table individually. This "truncate" optimization makes the delete run much faster. Prior to SQLite [version 3.6.5], the truncate optimization also meant that the [sqlite3_changes()] and [sqlite3_total_changes()] interfaces and the [count_changes pragma] will not actually return the number of deleted rows. That problem has been fixed as of [version 3.6.5]. <p>^The truncate optimization can be permanently disabled for all queries by recompiling SQLite with the [SQLITE_OMIT_TRUNCATE_OPTIMIZATION] compile-time switch.</p> <p>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.</p> <h3>Use Of LIMIT</h3> <p>^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:</p> <tcl>BubbleDiagram delete-stmt-limited</tcl> <p>^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 on a DELETE statement is used only to determine which rows fall within the LIMIT. ^The order in which rows are deleted is arbitrary and is not determined by the ORDER BY clause.</p> <p>^The presence of a LIMIT clause defeats the truncate optimization causing all rows being deleted to be visited.</p> <tcl> ############################################################################### Section {DETACH DATABASE} detach *DETACH BubbleDiagram detach-stmt 1 </tcl> <p>^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.</p> <p>^This statement will fail if SQLite is in the middle of a transaction.</p> <tcl> ############################################################################## Section {DROP INDEX} dropindex {{DROP INDEX}} BubbleDiagram drop-index-stmt 1 </tcl> <p>^The DROP INDEX statement removes an index added with the [CREATE INDEX] statement. The index is completely removed from the disk. The only way to recover the index is to reenter the appropriate [CREATE INDEX] command.</p> <p>^The DROP INDEX statement does not reduce the size of the database file in the default mode. ^Disk space released by the DROP INDEX command is retained for use by 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.</p> <tcl> ############################################################################## Section {DROP TABLE} droptable {{DROP TABLE}} BubbleDiagram drop-table-stmt 1 </tcl> <p>^The DROP TABLE statement removes a table added with the [CREATE TABLE] statement. The name specified is the table name. ^The dropped table is completely removed from the database schema and the disk file. The table can not be recovered. ^All indices and triggers associated with the table are also deleted.</p> <p>^The DROP TABLE statement does not reduce the size of the database file in the default mode. ^Disk space released by the DROP TABLE command is retained for reuse by subsequent [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.</p> <p>^The optional IF EXISTS clause suppresses the error that would normally result if the table does not exist.</p> <p>^If [foreign key constraints] are enabled, a DROP TABLE command performs an implicit [DELETE | DELETE FROM <tbl>] command before removing the table from the database schema. ^Any triggers attached to the table are dropped from the database schema before the implicit DELETE FROM <tbl> is executed, so this cannot cause any triggers to fire. By contrast, ^an |
︙ | ︙ | |||
1196 1197 1198 1199 1200 1201 1202 | <tcl> ############################################################################## Section {DROP TRIGGER} droptrigger {{DROP TRIGGER}} BubbleDiagram drop-trigger-stmt 1 </tcl> | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | 1192 1193 1194 1195 1196 1197 1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216 1217 1218 1219 1220 1221 1222 1223 1224 1225 1226 1227 1228 1229 1230 1231 1232 1233 1234 1235 1236 1237 1238 1239 1240 1241 1242 1243 1244 1245 1246 1247 1248 1249 1250 1251 1252 1253 1254 1255 1256 1257 1258 1259 1260 1261 1262 1263 1264 1265 1266 1267 1268 1269 1270 1271 1272 1273 1274 1275 1276 1277 1278 1279 1280 1281 1282 1283 1284 1285 1286 1287 1288 1289 1290 1291 1292 1293 1294 1295 1296 1297 1298 1299 1300 1301 1302 1303 1304 1305 1306 1307 1308 1309 1310 1311 1312 1313 1314 1315 1316 1317 1318 1319 1320 1321 1322 1323 1324 1325 1326 1327 1328 1329 1330 1331 1332 1333 1334 1335 1336 1337 1338 1339 1340 1341 1342 1343 1344 1345 1346 1347 1348 1349 1350 1351 1352 1353 | <tcl> ############################################################################## Section {DROP TRIGGER} droptrigger {{DROP TRIGGER}} BubbleDiagram drop-trigger-stmt 1 </tcl> <p>^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.</p> <tcl> ############################################################################## Section {DROP VIEW} dropview {{DROP VIEW}} BubbleDiagram drop-view-stmt 1 </tcl> <p>^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.</p> <tcl> ############################################################################## Section EXPLAIN explain EXPLAIN BubbleDiagram sql-stmt </tcl> <p>^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.</p> <p>^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.</p> <p>The output from EXPLAIN and EXPLAIN QUERY PLAN is intended for interactive analysis and troubleshooting only. The details of the output format are subject to change from one release of SQLite to the next. Applications should not use EXPLAIN or EXPLAIN QUERY PLAN since their exact behavior is undocumented, unspecified, and variable.</p> <tcl> ############################################################################## Section expression expr {*expression {expression syntax}} BubbleDiagram expr 1 BubbleDiagram literal-value BubbleDiagram signed-number BubbleDiagram raise-function </tcl> <p>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.</p> <tcl>hd_fragment binaryops {binary operators}</tcl> <h3>Operators</h3> <p>^(SQLite understands the following binary operators, in order from highest to lowest precedence:</p> <blockquote><pre> <font color="#2c2cf0"><big>|| * / % + - << >> & | < <= > >= = == != <> </big>IS IN LIKE GLOB MATCH REGEXP AND OR</font> </pre></blockquote>)^ <p>^(Supported unary prefix operators are these:</p> <blockquote><pre> <font color="#2c2cf0"><big>- + ~ NOT</big></font> </pre></blockquote>)^ <p>^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.</p> <tcl>hd_puts " <p>^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.</p>"</tcl> <p>Note that there are two variations of the equals and not equals operators. ^Equals can be either <tcl> 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.</p> <p>^The result of any binary operator is a numeric value, except for the [Operator ||] concatenation operator which gives a string result.</p>" hd_fragment {isisnot} {IS operator} {IS NOT operator} hd_puts "<p>^The [Operator IS] and [Operator {IS NOT}] operators work like [Operator =] and [Operator !=] except that NULL values compare equal to one another. ^[Operator IS] and [Operator {IS NOT}] have the same precedence as [Operator =]." <tcl>hd_fragment litvalue {literal value}</tcl> <h3>Literal Values</h3> <p> ^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:</p> <blockquote><pre> X'53514C697465' </pre></blockquote>)^ <p> ^A literal value can also be the token "NULL". </p> <tcl>hd_fragment varparam parameter parameters {bound parameter} {bound parameters}</tcl> <h3>Parameters</h3> <p> 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: </p> <blockquote> <table> <tr> <td align="right" valign="top"><b>?</b><i>NNN</i></td><td width="20"></td> <td>A question mark followed by a number <i>NNN</i> holds a spot for the NNN-th parameter. NNN must be between 1 and [SQLITE_MAX_VARIABLE_NUMBER].</td> |
︙ | ︙ | |||
1379 1380 1381 1382 1383 1384 1385 | 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 [http://www.tcl.tk/ | Tcl programming language]. The presence of this syntax results from the fact that SQLite is really a [Tcl extension] that has escaped into the wild.</td> </tr> </table> | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | | | | | | | | | | | | > | | | | | | | | | | | | 1375 1376 1377 1378 1379 1380 1381 1382 1383 1384 1385 1386 1387 1388 1389 1390 1391 1392 1393 1394 1395 1396 1397 1398 1399 1400 1401 1402 1403 1404 1405 1406 1407 1408 1409 1410 1411 1412 1413 1414 1415 1416 1417 1418 1419 1420 1421 1422 1423 1424 1425 1426 1427 1428 1429 1430 1431 1432 1433 1434 1435 1436 1437 1438 1439 1440 1441 1442 1443 1444 1445 1446 1447 1448 1449 1450 1451 1452 1453 1454 1455 1456 1457 1458 1459 1460 1461 1462 1463 1464 1465 1466 1467 1468 1469 1470 1471 1472 1473 1474 1475 1476 1477 1478 1479 1480 1481 1482 1483 1484 1485 1486 1487 1488 1489 1490 1491 1492 1493 1494 1495 1496 1497 1498 1499 1500 1501 1502 1503 1504 1505 1506 1507 1508 1509 1510 1511 1512 1513 1514 1515 1516 1517 1518 1519 1520 1521 1522 1523 1524 1525 1526 1527 1528 1529 1530 1531 1532 1533 1534 1535 1536 1537 1538 1539 1540 1541 1542 1543 1544 1545 1546 1547 1548 1549 1550 1551 | 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 [http://www.tcl.tk/ | Tcl programming language]. The presence of this syntax results from the fact that SQLite is really a [Tcl extension] that has escaped into the wild.</td> </tr> </table> </blockquote>)^ <p>^Parameters that are not assigned values using [sqlite3_bind_blob() | sqlite3_bind()] are treated as NULL.</p> <tcl>hd_fragment like LIKE ESCAPE</tcl> <h3>The LIKE and GLOB operators</h3> <p>^The LIKE operator does a pattern matching comparison. ^The operand to the right of the LIKE operator contains the pattern and the left hand operand contains the string to match against the pattern. <tcl>hd_puts "^A percent symbol (\"%\") in the LIKE pattern matches any sequence of zero or more characters in the string. ^An underscore (\"_\") in the LIKE pattern matches any single character in the string. ^Any other character matches itself or 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 <b>'a' LIKE 'A'</b> is TRUE but <b>'æ' LIKE 'Æ'</b> is FALSE.)</p>"</tcl> <p>^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. <p>^The infix LIKE operator is implemented by calling the application-defined SQL functions [like(<i>Y</i>,<i>X</i>)] or [like(<i>Y</i>,<i>X</i>,<i>Z</i>)]</a>.</p> <p>^The LIKE operator can be made case sensitive using the [case_sensitive_like pragma].</p> <tcl>hd_fragment glob GLOB</tcl> <p>^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(<i>Y</i>,<i>X</i>)] and can be modified by overriding that function.</p> <tcl>hd_fragment regexp REGEXP</tcl> <p>^The REGEXP operator is a special syntax for the regexp() user function. ^No regexp() user function is defined by default and so use of the REGEXP operator will normally result in an error message. ^If a [application-defined SQL function] named "regexp" is added at run-time, that function will be called in order to implement the REGEXP operator.</p> <tcl>hd_fragment match MATCH</tcl> <p>^The MATCH operator is a special syntax for the match() application-defined function. ^The default match() function implementation raises an exception and is not really useful for anything. ^But extensions can override the match() function with more helpful logic.</p> <tcl>hd_fragment between BETWEEN</tcl> <h3>The BETWEEN operator</h3> <p>^(The BETWEEN operator is equivalent to a pair of comparisons. "<i>a</i> <b>BETWEEN</b> <i>b</i> <b>AND</b> <i>c</i>" is equivalent to "<i>a</i><b>>=</b><i>b</i> <b>AND</b> <i>a</i><b><=</b><i>c</i>".)^ ^The precedence of the BETWEEN operator is the same as the precedence as operators <b>==</b> and <b>!=</b> and <b>LIKE</b> and groups left to right. <tcl>hd_fragment {CASE expression}</tcl> <h3>The CASE expression</h3> <p>^(A CASE expression consists of the CASE keyword, an optional expression (the "base" expression), one or more WHEN...THEN clauses, an optional ELSE clause, and a closing END keyword.)^ ^If the CASE as a base expression, then that expression is evaluated once and the result is compared to the expression in between the WHEN and THEN keywords for the WHEN clauses moving from left to right until a match is found or all WHEN clauses are tested. ^As soon as a match is found, the expression that occurs after then THEN keyword becomes the result of the overall CASE expression. ^None of the other expressions to the left of the THEN expression are ever evaluated. ^If no WHEN terms match the base expression, then the expression in the ELSE clause is evaluated and becomes the result of the CASE expression, or the result of the CASE is NULL if there is no ELSE clause.</p> <p>^If a CASE expression has no base expression, then the WHEN phrases are examined from left to write until a WHEN phrase where the expression between the WHEN and THEN keywords evaluates to true. ^A NULL value is considered false for the purposes of this test. ^When a true WHEN expression is discovered, the corresponding THEN expression is evaluated and becomes the result of the overall CASE expression. ^If no WHEN expression evaluates to to true, then the ELSE expression becomes the result if the ELSE clause exists, otherwise the result is NULL.</p> <p>^The base expression is evaluated exactly once. ^WHEN expressions are evaluated from left to write until a match is found. ^WHEN expressions to the right the matching WHEN are never evaluated. ^If any WHEN expression matches, its THEN expression is evaluated and becomes the result of the overall CASE expression. ^No THEN expression is evaluated except the one THEN expression that corresponds to a matching WHEN. ^The ELSE expression is only evaluated if no WHEN expression match.</p> <p>^If the base expression is NULL then the result of the CASE is the result of the ELSE expression if it exists, or NULL if the ELSE clause is omitted.</p> <h3>Table Column Names</h3> <p>^A column name can be any of the names defined in the [CREATE TABLE] statement or one of the following special identifiers: "<b>ROWID</b>", "<b>OID</b>", or "<b>_ROWID_</b>". ^These special identifiers all describe the unique integer key (the [rowid]) associated with every row of every table. ^The special identifiers only refer to the row key if the [CREATE TABLE] statement does not define a real column with the same name. ^The rowid can be used anywhere a regular column can be used.</p> <h3>Subqueries</h3> <p>^[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 values 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.</p> <p>^When a SELECT is the right operand of the IN operator, the IN operator returns TRUE if the SELECT result contains no NULLs and if the left operand matches any of the values in the SELECT result. ^The IN operator may be preceded by the NOT keyword to invert the sense of the test.</p> <p>^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.</p> <h3>CAST expressions</h3> <p>^A CAST expression changes the [datatype] of the <expr> 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.)^</p> <h3>Functions</h3> <p>^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.</p> <tcl> ############################################################################## Section {Core Functions} corefunc {*corefunc} proc funcdef {syntax keywords desc} { hd_puts {<tr>} |
︙ | ︙ | |||
1813 1814 1815 1816 1817 1818 1819 | <p> SQLite supports five date and time functions as follows: </p> <p> <ol> | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | 1849 1850 1851 1852 1853 1854 1855 1856 1857 1858 1859 1860 1861 1862 1863 1864 1865 1866 1867 1868 1869 1870 1871 1872 1873 1874 1875 1876 1877 1878 1879 1880 1881 1882 1883 1884 1885 1886 1887 1888 1889 1890 1891 1892 1893 1894 1895 1896 1897 1898 1899 1900 1901 1902 1903 1904 1905 1906 1907 1908 1909 1910 1911 1912 1913 1914 1915 1916 1917 1918 1919 1920 1921 1922 1923 1924 1925 1926 1927 1928 1929 1930 1931 1932 1933 1934 1935 1936 1937 1938 1939 1940 1941 1942 1943 1944 1945 1946 1947 1948 1949 1950 1951 1952 1953 1954 1955 1956 1957 1958 1959 1960 1961 1962 1963 1964 1965 1966 1967 1968 1969 1970 1971 1972 1973 1974 1975 1976 1977 1978 1979 1980 1981 1982 1983 1984 1985 1986 1987 1988 1989 1990 1991 1992 1993 1994 1995 1996 1997 1998 1999 2000 2001 2002 2003 2004 2005 2006 2007 2008 2009 2010 2011 2012 2013 2014 2015 2016 2017 2018 2019 2020 2021 2022 2023 2024 2025 2026 2027 2028 2029 2030 2031 2032 2033 2034 2035 2036 2037 2038 2039 2040 2041 2042 2043 2044 2045 2046 2047 2048 2049 2050 2051 2052 2053 2054 2055 2056 2057 2058 2059 2060 2061 2062 2063 2064 2065 2066 2067 2068 2069 2070 2071 2072 2073 2074 2075 2076 2077 2078 2079 2080 2081 2082 2083 2084 2085 2086 2087 2088 2089 2090 2091 2092 2093 2094 2095 2096 2097 2098 2099 2100 2101 2102 2103 2104 2105 2106 | <p> SQLite supports five date and time functions as follows: </p> <p> <ol> <li> <b>^(date(</b><i>timestring, modifier, modifier, ...</i><b>))^</b> </li> <li> <b>^(time(</b><i>timestring, modifier, modifier, ...</i><b>))^</b> </li> <li> <b>^(datetime(</b><i>timestring, modifier, modifier, ...</i><b>))^</b> </li> <li> <b>^(julianday(</b><i>timestring, modifier, modifier, ...</i><b>))^</b> </li> <li> <b>^(strftime(</b><i>format, timestring, modifier, modifier, ...</i><b>))^</b> </li> </ol> <p> ^All five date and time functions take a time string as an argument. ^The time string is followed by zero or more modifiers. ^The strftime() function also takes a format string as its first argument. </p> <p> The date and time functions use a subset of [http://en.wikipedia.org/wiki/ISO_8601 | IS0-8601] date and time formats. ^The date() function returns the date in this format: YYYY-MM-DD. ^The time() function returns the time as HH:MM:SS. ^The datetime() function returns "YYYY-MM-DD HH:MM:SS". ^(The julianday() function returns the [http://en.wikipedia.org/wiki/Julian_day | Julian day] - the number of days since noon in Greenwich on November 24, 4714 B.C. ([http://en.wikipedia.org/wiki/Proleptic_Gregorian_calendar | Proleptic Gregorian calendar]).)^ ^The strftime() routine returns the date formatted according to the format string specified as the first argument. ^The format string supports the most common substitutions found in the [http://opengroup.org/onlinepubs/007908799/xsh/strftime.html | strftime() function] from the standard C library plus two new substitutions, %f and %J. ^(The following is a complete list of valid strftime() substitutions: </p> <blockquote> <table border="0" cellpadding="0" cellspacing="0"> <tr><td><td width="10"><td></tr> <tr><td> %d <td><td> day of month: 00 <tr><td> %f <td><td> fractional seconds: SS.SSS <tr><td> %H <td><td> hour: 00-24 <tr><td> %j <td><td> day of year: 001-366 <tr><td> %J <td><td> Julian day number <tr><td> %m <td><td> month: 01-12 <tr><td> %M <td><td> minute: 00-59 <tr><td> %s <td><td> seconds since 1970-01-01 <tr><td> %S <td><td> seconds: 00-59 <tr><td> %w <td><td> day of week 0-6 with sunday==0 <tr><td> %W <td><td> week of year: 00-53 <tr><td> %Y <td><td> year: 0000-9999 <tr><td> %% <td><td> % </table> </blockquote>)^ <p> ^(Notice that all other date and time functions can be expressed in terms of strftime(): </p> <blockquote> <table border="0" cellpadding="0" cellspacing="0"> <tr><td><b>Function</b><td width="30"><td><b>Equivalent strftime()</b> <tr><td> date(...) <td><td> strftime('%Y-%m-%d', ...) <tr><td> time(...) <td><td> strftime('%H:%M:%S', ...) <tr><td> datetime(...) <td><td> strftime('%Y-%m-%d %H:%M:%S', ...) <tr><td> julianday(...) <td><td> strftime('%J', ...) </table> </blockquote>)^ <p> The only reasons for providing functions other than strftime() is for convenience and for efficiency. </p> <h3>Time Strings</h3> <p>^(A time string can be in any of the following formats:</p> <ol> <li> <i>YYYY-MM-DD</i> <li> <i>YYYY-MM-DD HH:MM</i> <li> <i>YYYY-MM-DD HH:MM:SS</i> <li> <i>YYYY-MM-DD HH:MM:SS.SSS</i> <li> <i>YYYY-MM-DD</i><b>T</b><i>HH:MM</i> <li> <i>YYYY-MM-DD</i><b>T</b><i>HH:MM:SS</i> <li> <i>YYYY-MM-DD</i><b>T</b><i>HH:MM:SS.SSS</i> <li> <i>HH:MM</i> <li> <i>HH:MM:SS</i> <li> <i>HH:MM:SS.SSS</i> <li> <b>now</b> <li> <i>DDDDDDDDDD</i> </ol>)^ <p> ^In formats 5 through 7, the "T" is a literal character separating the date and the time, as required by [http://www.w3c.org/TR/NOTE-datetime | ISO-8601]. ^Formats 8 through 10 that specify only a time assume a date of 2000-01-01. Format 11, the string 'now', is converted into the current date and time as obtained from the xCurrentTime method of the [sqlite3_vfs] object in use. ^[http://en.wikipedia.org/wiki/Coordinated_Universal_Time | Universal Coordinated Time (UTC)] is used. ^Format 12 is the [http://en.wikipedia.org/wiki/Julian_day | Julian day number] expressed as a floating point value. </p> <h3>Modifiers</h3> <p>^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.</p> <ol> <li> NNN days <li> NNN hours <li> NNN minutes <li> NNN.NNNN seconds <li> NNN months <li> NNN years <li> start of month <li> start of year <li> start of day <li> weekday N <li> unixepoch <li> localtime <li> utc </ol>)^ <p>^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.</p> <p>^The "start of" modifiers (7 through 9) shift the date backwards to the beginning of the current month, year or day.</p> <p>^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.</p> <p>^The "unixepoch" modifier (11) only works if it immediately follows a timestring in the DDDDDDDDDD format. ^This modifier causes the DDDDDDDDDD to be interpreted not as a Julian day number as it normally would be, but as [http://en.wikipedia.org/wiki/Unix_time | Unix Time] - the number of seconds since 1970. If the "unixepoch" modifier does not follow a timestring of the form DDDDDDDDDD which expresses the number of seconds since 1970 or if other modifiers separate the "unixepoch" modifier from prior DDDDDDDDDD then the behavior is undefined. Due to precision limitations imposed by the implementations use of 64-bit integers, the "unixepoch" modifier only works for dates between 0000-01-01 00:00:00 and 5352-11-01 10:52:47 (unix times of -62167219200 through 10675199167).</p> <p>^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.</p> <h3>Examples</h3> ^(<p>Compute the current date.<p> <blockquote>SELECT date('now');</blockquote>)^ ^(<p>Compute the last day of the current month.</p> <blockquote>SELECT date('now','start of month','+1 month','-1 day'); </blockquote>)^ ^(<p>Compute the date and time given a unix timestamp 1092941466.</p> <blockquote> SELECT datetime(1092941466, 'unixepoch'); </blockquote>)^ ^(<p>Compute the date and time given a unix timestamp 1092941466, and compensate for your local timezone.</p> <blockquote> SELECT datetime(1092941466, 'unixepoch', 'localtime'); </blockquote>)^ ^(<p>Compute the current unix timestamp.</p> <blockquote> SELECT strftime('%s','now'); </blockquote>)^ ^(<p>Compute the number of days since the signing of the US Declaration of Independent.</p> <blockquote> SELECT julianday('now') - julianday('1776-07-04'); </blockquote>)^ ^(<p>Compute the number of seconds since a particular moment in 2004:</p> <blockquote> SELECT strftime('%s','now') - strftime('%s','2004-01-01 02:34:56'); </blockquote>)^ ^(<p> Compute the date of the first Tuesday in October for the current year. </p> <blockquote> SELECT date('now','start of year','+9 months','weekday 2'); </blockquote>)^ ^(<p>Compute the time since the unix epoch in seconds (like strftime('%s','now') except includes fractional part):</p> <blockquote> SELECT (julianday('now') - 2440587.5)*86400.0; </blockquote>)^ <h3>Caveats And Bugs</h3> <p>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.)^</p> <p>^(These functions only work for dates between 0000-01-01 00:00:00 and 9999-12-31 23:59:59 (julidan day numbers 1721059.5 through 5373484.5).)^ For dates outside that range, the results of these functions are undefined.</p> <p>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. |
︙ | ︙ | |||
2085 2086 2087 2088 2089 2090 2091 | <p> The aggregate functions shown below are available by default. Additional aggregate functions written in C may be added using the [sqlite3_create_function()]</a> API.</p> <p> | | | | > | | | | > | | | > | | | > | | | > | | | > | | | | | | | | | | | | | | | | | > > > > | | | | | | | | | | | | > | | | | | | | | | | | > | | | > | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | > | | | | | | | | | | | | | | | | | | | | | | 2121 2122 2123 2124 2125 2126 2127 2128 2129 2130 2131 2132 2133 2134 2135 2136 2137 2138 2139 2140 2141 2142 2143 2144 2145 2146 2147 2148 2149 2150 2151 2152 2153 2154 2155 2156 2157 2158 2159 2160 2161 2162 2163 2164 2165 2166 2167 2168 2169 2170 2171 2172 2173 2174 2175 2176 2177 2178 2179 2180 2181 2182 2183 2184 2185 2186 2187 2188 2189 2190 2191 2192 2193 2194 2195 2196 2197 2198 2199 2200 2201 2202 2203 2204 2205 2206 2207 2208 2209 2210 2211 2212 2213 2214 2215 2216 2217 2218 2219 2220 2221 2222 2223 2224 2225 2226 2227 2228 2229 2230 2231 2232 2233 2234 2235 2236 2237 2238 2239 2240 2241 2242 2243 2244 2245 2246 2247 2248 2249 2250 2251 2252 2253 2254 2255 2256 2257 2258 2259 2260 2261 2262 2263 2264 2265 2266 2267 2268 2269 2270 2271 2272 2273 2274 2275 2276 2277 2278 2279 2280 2281 2282 2283 2284 2285 2286 2287 2288 2289 2290 2291 2292 2293 2294 2295 2296 2297 2298 2299 2300 2301 2302 2303 2304 2305 2306 2307 2308 2309 2310 2311 2312 2313 2314 2315 2316 2317 2318 2319 2320 2321 2322 2323 2324 2325 2326 2327 2328 2329 2330 2331 2332 2333 2334 2335 2336 2337 2338 2339 2340 2341 2342 2343 2344 2345 2346 2347 2348 2349 2350 2351 2352 2353 2354 2355 2356 2357 2358 2359 2360 2361 2362 2363 2364 2365 2366 2367 2368 2369 2370 2371 2372 2373 2374 2375 2376 2377 2378 2379 2380 2381 2382 2383 2384 2385 2386 2387 2388 2389 2390 2391 2392 2393 2394 2395 2396 2397 2398 2399 2400 2401 2402 2403 2404 2405 2406 2407 2408 2409 2410 2411 2412 2413 2414 2415 2416 2417 2418 2419 2420 2421 2422 2423 2424 2425 2426 2427 2428 2429 2430 2431 2432 2433 2434 2435 2436 2437 2438 2439 2440 2441 2442 2443 2444 2445 2446 2447 2448 2449 2450 2451 2452 2453 2454 2455 2456 2457 2458 2459 2460 2461 2462 2463 2464 2465 2466 2467 2468 2469 2470 2471 2472 2473 2474 2475 2476 2477 2478 2479 2480 2481 2482 2483 2484 2485 2486 2487 2488 2489 2490 2491 2492 2493 2494 2495 2496 2497 2498 2499 2500 2501 2502 2503 2504 2505 2506 2507 2508 2509 2510 2511 2512 2513 2514 2515 2516 2517 2518 2519 2520 2521 2522 2523 2524 2525 2526 2527 2528 2529 2530 2531 2532 2533 2534 2535 2536 2537 2538 2539 2540 2541 2542 2543 2544 2545 2546 2547 2548 2549 2550 2551 2552 2553 2554 2555 2556 2557 2558 2559 2560 2561 2562 2563 2564 2565 2566 2567 2568 2569 2570 2571 2572 2573 2574 2575 2576 2577 2578 2579 2580 2581 2582 2583 2584 2585 2586 2587 2588 2589 2590 2591 2592 2593 2594 2595 2596 2597 2598 2599 2600 2601 2602 2603 2604 2605 2606 2607 2608 2609 2610 2611 2612 2613 2614 2615 2616 2617 2618 2619 2620 2621 2622 2623 2624 2625 2626 | <p> The aggregate functions shown below are available by default. Additional aggregate functions written in C may be added using the [sqlite3_create_function()]</a> API.</p> <p> ^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. </p> <table border=0 cellpadding=10> <tcl> funcdef {avg(X)} {*avg {avg() aggregate function}} { ^The avg() function returns the average value of all non-NULL <i>X</i> within a group. ^String and BLOB values that do not look like numbers are interpreted as 0. ^The result of avg() is always a floating point value as long as at there is at least one non-NULL input even if all inputs are integers. ^The result of avg() is NULL if and only if there are no non-NULL inputs. } funcdef {count(X) count(*)} {*count {count() aggregate function}} { ^The count(X) function returns a count of the number of times that <i>X</i> is not NULL in a group. ^The count(*) function (with no arguments) returns the total number of rows in the group. } funcdef {group_concat(X) group_concat(X,Y)} { *group_concat {group_concat() aggregate function} } { ^The group_concat() function returns a string which is the concatenation of all non-NULL values of <i>X</i>. ^If parameter <i>Y</i> is present then is is used as the separator between instances of <i>X</i>. ^A comma (",") is used as the separator if <i>Y</i> is omitted. The order of the concatenated elements is arbitrary. } funcdef {max(X)} {*maxAggFunc *agg_max {max() aggregate function}} { ^The max() aggregate function returns the maximum value of all values in the group. ^The maximum value is the value that would be returned last in an ORDER BY on the same column. ^NULL is returned if and only if there are no non-NULL values in the group. } funcdef {min(X)} {*minAggFunc *agg_min {min() aggregate function}} { ^The min() aggregate function returns the minimum non-NULL value of all values in the group. ^The minimum value is the first non-NULL value that would appear in an ORDER BY of the column. ^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 {sum() aggregate function} {total() aggregate function} } { The sum() aggregate function returns 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.</p> <p>^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.</p> <p>^Sum() will throw an "integer overflow" exception if all inputs are integers or NULL and an integer overflow occurs at any point during the computation. ^Total() never throws an integer overflow. } </tcl> </table> <tcl> ############################################################################## Section INSERT insert {INSERT *INSERTs} BubbleDiagram insert-stmt 1 </tcl> <p>The INSERT statement comes in three 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. </p> <p>^The second form of the INSERT statement takes its 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.</p> <p>^The third form of an INSERT statement is with DEFAULT VALUES. ^The INSERT ... DEFAULT VALUES statement simply creates a single new row in the table in which each column is filled with its default value.</p> <p>^The optional conflict-clause allows the specification of an alternative constraint conflict resolution algorithm to use during this one INSERT command. See the section titled [ON CONFLICT] for additional information. ^For compatibility with MySQL, the parser allows the use of the single keyword <a href="lang_replace.html">REPLACE</a> as an alias for "INSERT OR REPLACE". </p> <p>^The optional "<i>database-name</i><b>.</b>" prefix on the <i>table-name</i> is support for top-level INSERT statements only. ^The table name must be unqualified for INSERT statements that occur within [CREATE TRIGGER] statements. ^Similarly, the "DEFAULT VALUES" form of the INSERT statement is supported for top-level INSERT statements only and not for INSERT statements within triggers. <p> <tcl> ############################################################################## Section {ON CONFLICT clause} conflict {{conflict clause} {ON CONFLICT}} BubbleDiagram conflict-clause </tcl> <p>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.</p> <p>^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.</p> <p>^The ON CONFLICT clause specifies an algorithm used to resolve constraint conflicts. ^There are five conflict resolution algorithm choices: ROLLBACK, ABORT, FAIL, IGNORE, and REPLACE. ^The default conflict resolution algorithm is ABORT. This is what they mean:</p> <dl> <dt><b>ROLLBACK</b></dt> <dd><p>^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.</p></dd> <dt><b>ABORT</b></dt> <dd><p>^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.</p></dd> <dt><b>FAIL</b></dt> <dd><p>^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.</p></dd> <dt><b>IGNORE</b></dt> <dd><p>^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 when the IGNORE conflict resolution algorithm is used.</p></dd> <dt><b>REPLACE</b></dt> <dd><p>^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 following REPLACE. ^No error is returned by the REPLACE conflict resolution. ^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.</p> <p>^When this conflict resolution strategy deletes rows in order to satisfy a constraint, [CREATE TRIGGER | delete triggers] only fire if [recursive_triggers pragma | recursive triggers] are enabled.</p> <p>^The [sqlite3_update_hook | update hook] is not invoked for rows that are deleted by an OR REPLACE resolution. ^Nor is the [sqlite3_changes | change counter] incremented. The exceptional behaviors defined in this paragraph might change in a future release.</p> </dl> <p>^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.</p> <tcl> ############################################################################## Section REINDEX reindex REINDEX BubbleDiagram reindex-stmt 1 </tcl> <p>^The REINDEX command is used to delete and recreate indices from scratch. This is useful when the definition of a collation sequence has changed. </p> <p>^In the first form, all indices in all attached databases that use the named collation sequence are recreated. ^(In the second form, if <i>[database-name.]table/index-name</i> 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. </p> <p>^If no <i>database-name</i> 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 <i>database-name</i> when reindexing a specific table or index. <tcl> ############################################################################### Section REPLACE replace REPLACE </tcl> <p>^The REPLACE command is an alias for the "[ON CONFLICT | INSERT OR REPLACE]" variant of the [INSERT] command. This alias is provided for compatibility other SQL database engines. See the [INSERT] command documentation for additional information.</p> <tcl> ############################################################################### 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 </tcl> <p>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.</p>)^ <p>^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.</p> <p>^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. </p> <p>^The WHERE clause can be used to limit the number of rows over which the query operates.</p> <p>^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 <em>not</em> 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.</p> <p>^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.</p> <p>Each term of an ORDER BY expression is processed as follows:</p> <ol> <li><p>^If the ORDER BY expression is a constant integer K then the output is ordered by the K-th column of the result set.</p></li> <li><p>^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.</p></li> <li><p>^Otherwise, the ORDER BY expression is evaluated and the output is ordered by the value of that expression.</p></li> </ol> <p>^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.</p> <p>^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. </p> <p>^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.</p> <tcl> ############################################################################## Section UPDATE update {UPDATE *UPDATEs} BubbleDiagram update-stmt 1 BubbleDiagram qualified-table-name </tcl> <p>^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.</p> <p>^The optional conflict-clause allows the specification of an alternative constraint conflict resolution algorithm to use during this one UPDATE command. See the section titled [ON CONFLICT] for additional information.</p> <h3>Restrictions on UPDATE Statements Within CREATE TRIGGER</h3> <p>^There are additional syntax restrictions on UPDATE statements that occur within the body of a [CREATE TRIGGER] statement. ^The <i>table-name</i> of the UPDATE must be unqualified. ^(In other words, the <i>database-name</i><b>.</b> prefix on the table name of the UPDATE is not allowed within triggers. ^The table to be updated must be in the same database as the table to which the trigger is attached.</p> <p>^The INDEXED BY and NOT INDEXED clauses are not allowed on UPDATE statements within triggers.</p> <p>^The LIMIT clause for UPDATE is unsupported within triggers.</p> <h3>Optional LIMIT and ORDER BY Clauses</h3> <p>^(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:</p> <tcl>BubbleDiagram update-stmt-limited</tcl> <p>^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 on an UPDATE statement is used only to determine which rows fall within the LIMIT. ^The order in which rows are modified is arbitrary and is not determined by the ORDER BY clause.</p> <tcl> ############################################################################## Section VACUUM vacuum VACUUM BubbleDiagram vacuum-stmt 1 </tcl> <p>^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.</p> <p>^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.</p> <p>^The VACUUM command may change the [ROWID | ROWIDs] of entries in tables that do not have an explicit [INTEGER PRIMARY KEY].</p> <p>^VACUUM only works on the main database. It is not possible to VACUUM an attached database file.</p> <p>^The VACUUM command will fail if there is an active transaction. ^The VACUUM command is a no-op for in-memory databases.</p> <p>^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.</p> <p>^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.</p> <tcl> ############################################################################## Section {INDEXED BY} indexedby {{INDEXED BY} {NOT INDEXED}} </tcl> <p>^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:</p> <tcl> BubbleDiagram qualified-table-name BubbleDiagram single-source </tcl> <p>^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.)^</p> <p>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 <em>not</em> 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.</p> <p>The INDEXED BY clause is <em>not</em> 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 |
︙ | ︙ | |||
2731 2732 2733 2734 2735 2736 2737 | <p>If you want to use a keyword as a name, you need to quote it. There are three ways of quoting keywords in SQLite:</p> <p> <blockquote> <table> <tr> <td valign="top"><b>'keyword'</b></td><td width="20"></td> | | | | | | | | 2781 2782 2783 2784 2785 2786 2787 2788 2789 2790 2791 2792 2793 2794 2795 2796 2797 2798 2799 2800 2801 2802 2803 2804 2805 2806 2807 2808 2809 2810 2811 2812 2813 2814 2815 2816 2817 2818 2819 2820 2821 2822 2823 2824 2825 | <p>If you want to use a keyword as a name, you need to quote it. There are three ways of quoting keywords in SQLite:</p> <p> <blockquote> <table> <tr> <td valign="top"><b>'keyword'</b></td><td width="20"></td> <td>^A keyword in single quotes is a string literal.</td></tr> <tr> <td valign="top"><b>"keyword"</b></td><td></td> <td>^A keyword in double-quotes is an identifier</td></tr> <tr> <td valign="top"><b>[keyword]</b></td><td></td> <td>^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.</td></tr> <tr> <td valign="top"><b>`keyword`</b></td><td></td> <td>^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.</td></tr> </table> </blockquote> </p> <p>For resilience when confronted with historical SQL statements, SQLite will sometimes bend the quoting rules above:</p> <ul> <li><p>^If a keyword in single quotes (ex: <b>'key'</b> or <b>'glob'</b>) is used in a context where an identifier is allowed but where a string literal is not allowed, then the token is understood to be an identifier instead of a string literal. </p></li> <li><p>^If a keyword in double quotes (ex: <b>"key"</b> or <b>"glob"</b>) is used in a context where it cannot be resolved to an identifier but where a string literal is allowed, then the token is understood to be a string literal instead of an identifer.</p></li> </ul> <p>Programmers are cautioned not to use the two exceptions described in |
︙ | ︙ |
Changes to pages/opcode.in.
1 2 3 4 5 6 7 8 | <title>SQLite Virtual Machine Opcodes</title> <h2>SQLite Virtual Machine Opcodes</h2> <tcl> set fd [open $::SRC/src/vdbe.c r] set file [read $fd] close $fd | > | 1 2 3 4 5 6 7 8 9 | <title>SQLite Virtual Machine Opcodes</title> <tcl>hd_keywords {virtual machine instructions}</tcl> <h2>SQLite Virtual Machine Opcodes</h2> <tcl> set fd [open $::SRC/src/vdbe.c r] set file [read $fd] close $fd |
︙ | ︙ |