Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Add documentation for the STMT virtual table |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA3-256: |
3c1197562c4f74659df8efe03e1aadce |
User & Date: | drh 2017-06-29 18:17:08.084 |
Context
2017-06-29
| ||
18:27 | Mention the -withoutnulls option to the "db eval" method in the TCL interface documentation. (check-in: b1785f3962 user: drh tags: trunk) | |
18:17 | Add documentation for the STMT virtual table (check-in: 3c1197562c user: drh tags: trunk) | |
17:33 | Mention the sqlite3_prepare_v3() enhancement in the change log. (check-in: 9421ab387b user: drh tags: trunk) | |
Changes
Changes to pages/changes.in.
︙ | ︙ | |||
19 20 21 22 23 24 25 | set aChng($nChng) [list $date $desc $options] set xrefChng($date) $nChng incr nChng } chng {2017-08-31 (3.20.0)} { <li> Added the LSM1 extension | | | 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 | set aChng($nChng) [list $date $desc $options] set xrefChng($date) $nChng incr nChng } chng {2017-08-31 (3.20.0)} { <li> Added the LSM1 extension <li> Added the [STMT virtual table] extension <li> Added the [sqlite3_prepare_v3()] and [sqlite3_prepare16_v3()] interfaces with the extra "prepFlags" parameters. <li> Provide the [SQLITE_PREPARE_PERSISTENT] flag [sqlite3_prepare_v3()] and use it to limit [lookaside memory] misuse by [FTS3], [FTS5], and the [R-Tree extension] <li> Enhancements to the [command-line shell]: <ul> |
︙ | ︙ |
Changes to pages/compile.in.
︙ | ︙ | |||
979 980 981 982 983 984 985 986 987 988 989 990 991 992 | COMPILE_OPTION {SQLITE_ENABLE_STMT_SCANSTATUS} { This option enables the [sqlite3_stmt_scanstatus()] interface. The [sqlite3_stmt_scanstatus()] interface is normally omitted from the build because it imposes a small performance penalty, even on statements that do not use the feature. } COMPILE_OPTION {SQLITE_RTREE_INT_ONLY} { If this option is used together with [SQLITE_ENABLE_RTREE] then the [rtree | R*Tree extension] will only store 32-bit signed integer coordinates and all internal computations will be done using integers instead of floating point numbers. } | > > > > | 979 980 981 982 983 984 985 986 987 988 989 990 991 992 993 994 995 996 | COMPILE_OPTION {SQLITE_ENABLE_STMT_SCANSTATUS} { This option enables the [sqlite3_stmt_scanstatus()] interface. The [sqlite3_stmt_scanstatus()] interface is normally omitted from the build because it imposes a small performance penalty, even on statements that do not use the feature. } COMPILE_OPTION {SQLITE_ENABLE_STMTVTAB} { This compile-time option enables the [STMT virtual table] logic. } COMPILE_OPTION {SQLITE_RTREE_INT_ONLY} { If this option is used together with [SQLITE_ENABLE_RTREE] then the [rtree | R*Tree extension] will only store 32-bit signed integer coordinates and all internal computations will be done using integers instead of floating point numbers. } |
︙ | ︙ |
Changes to pages/optoverview.in.
︙ | ︙ | |||
1167 1168 1169 1170 1171 1172 1173 | Examples: } CODE { SELECT MIN(x) FROM table; SELECT MAX(x)+1 FROM table; } | | > | 1167 1168 1169 1170 1171 1172 1173 1174 1175 1176 1177 1178 1179 1180 1181 1182 | Examples: } CODE { SELECT MIN(x) FROM table; SELECT MAX(x)+1 FROM table; } HEADING 1 {Automatic Indexes} autoindex {automatic indexing} \ {Automatic indexing} {automatic indexes} PARAGRAPH { ^(When no indices are available to aid the evaluation of a query, SQLite might create an automatic index that lasts only for the duration of a single SQL statement.)^ Since the cost of constructing the automatic index is O(NlogN) (where N is the number of entries in the table) and the cost of |
︙ | ︙ |
Added pages/stmt.in.
> > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | 1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 | <title>The STMT Virtual Table</title> <tcl>hd_keywords stmt {STMT virtual table} \ {the STMT extension}</tcl> <fancy_format> <h1>Overview</h1> <p> The STMT extension implements an [eponymous-only virtual table] that provides information about all [prepared statements] associated with the [database connection]. </p> <p> The STMT extension is included in the [amalgamation] though it is disabled by default. The enable the STMT extension, use the [SQLITE_ENABLE_STMTVTAB] compile-time option. The STMT extension can also be loaded at run-time by compiling the extension into a shared library or DLL using the source code at [https://sqlite.org/src/file/ext/misc/stmt.c] and following the instructions for how to [compile loadable extensions]. </p> <p> The STMT extension is enabled in default builts of the [command-line shell]. <h1>Usage</h1> <p> The STMT virtual table is a read-only table that can be directly queried to access information about all prepared statements on the current database connection. For example: <codeblock> SELECT * FROM stmt; </codeblock> <p> A statement such as the above can be run immediately prior to invoking [sqlite3_close()] to confirm that all prepared statements have been [sqlite3_finalize|finalized] and to help identify and track down prepared statements that have "leaked" and missed finalization. <p> The STMT virtual table can also be used to access performance information about prepared statements, to aid in optimization an application. For example, to find out how much memory is being used by [prepared statements] that have never been used, once could run: <codeblock> SELECT sum(mem) FROM stmt WHERE run=0; </codeblock> <h2>Columns</h2> <p> The columns are provided by the STMT virtual table are summarized by the hypothetical CREATE TABLE statement show here: <codeblock> CREATE TABLE stmt( ptr INT, -- Numeric value of the pointer to sqlite3_stmt sql TEXT, -- Original SQL text ncol INT, -- Number of output columns ro BOOLEAN, -- True for "read only" statements busy BOOLEAN, -- True if the statement is current running nscan INT, -- Number of full-scan steps nsort INT, -- Number of sort operations naidx INT, -- Number of automatic index inserts nstep INT, -- Number of byte-code engine steps reprep INT, -- Number of reprepare operations run INT, -- Number of times this statement has been run mem INT -- Heap memory used by this statement ); </codeblock> <p>Future releases may add new output columns and may change the order of legacy columns. Further detail about the meaning of each column in the STMT virtual table is provided below: <ul> <li><p><b>ptr</b>: The numeric value of the pointer to the [sqlite3_stmt] object. <li><p><b>sql</b>: The original SQL text of the prepared statement. If the prepared statement is compiled using the [sqlite3_prepare()] interface, then the SQL text might not have been saved, in which case this column will be NULL. <li><p><b>ncol</b>: The number of columns in the result set of a query. For DML statements, this column has a value of 0. <li><p><b>ro</b>: The "read only" column. This column is true (non-zero) if the SQL statement is a query and false (zero) if it is a DML statement. <li><p><b>busy</b>: This field is true if the prepared statement is currently running. In other words, this field is true if [sqlite3_step()] has been called on the [prepared statement] at least once but [sqlite3_reset()] has not yet been called to reset it. <li><p><b>nscan</b>: This field is the number of times that the [bytecode engine] has stepped through a table as part of a full-table scan. A large number if this field may indicate an opportunity to improve performance by adding an index. This field is equivalent to the [SQLITE_STMTSTATUS_FULLSCAN_STEP] value. <li><p><b>nsort</b>: This field is the number of times that the [bytecode engine] had to sort. A positive value in this field may indicate an opportunity to improve performance by adding an index that will cause the query results to appear naturally in the desired order. This field is equivalent to the [SQLITE_STMTSTATUS_SORT] value. <li><p><b>naidx</b>: This field is the number of rows that have been inserted into [automatic indexes]. A positive value in this field may indicate an opportunity to improve performance by adding a named index that take the place of the automatic index. This field is equivalent to the [SQLITE_STMTSTATUS_AUTOINDEX] value. <li><p><b>nstep</b>: This field is the number of [bytecode engine] operations that have been performed for the prepared statement. This field can be used as a proxy for how much CPU time a statement has used. This field is equivalent to the [SQLITE_STMTSTATUS_VM_STEP] value. <li><p><b>reprep</b>: This field is the number of times that the statement has had to be reprepared due to schema changes or changes to parameter bindings. This field is equivalent to the [SQLITE_STMTSTATUS_REPREPARE] value. <li><p><b>run</b>: This field is the number of times that the statement has been run. This field is equivalent to the [SQLITE_STMTSTATUS_RUN] value. <li><p><b>mem</b>: This field is the number of bytes of heap storage used by the prepared statement. This field is equivalent to the [SQLITE_STMTSTATUS_MEMUSED] value. </ul> |