Documentation Source Text

Check-in [8b6ed636e3]
Login

Many hyperlinks are disabled.
Use anonymous login to enable hyperlinks.

Overview
Comment:Add a new documentation page that talks specifically about indexes on expressions.
Downloads: Tarball | ZIP archive
Timelines: family | ancestors | descendants | both | trunk
Files: files | file ages | folders
SHA1: 8b6ed636e34f18013a23b361ceac7d11101c2ea4
User & Date: drh 2015-10-07 19:35:52.529
Context
2015-10-07
19:40
Link the optoverview.html document to the new expridx.html document. (check-in: 47d33de042 user: drh tags: trunk)
19:35
Add a new documentation page that talks specifically about indexes on expressions. (check-in: 8b6ed636e3 user: drh tags: trunk)
18:25
Mention enhancements to dbstat in the change log. (check-in: e738239518 user: drh tags: trunk)
Changes
Unified Diff Ignore Whitespace Patch
Changes to pages/changes.in.
16
17
18
19
20
21
22

23
24
25
26
27
28
29
30
31
32


33
34
35
36
37
38
39
  global nChng aChng
  set aChng($nChng) [list $date $desc $options]
  incr nChng
}

chng {2015-11-01 (3.8.12)} {
<p><b>New Features And Enhancements:</b>

<li>The [CREATE VIEW] statement now accepts an optional list of
    column names following the view name.
<li>Added support for [indexes on expressions].
<li>Added support for [table-valued functions] in the FROM clause of a
    [SELECT] statement.
<li>Added support for [eponymous virtual tables].
<li>Added [the json1 extension] module in the source tree.
<li>A [VIEW] may now reference undefined tables and functions when
    initially created.  Missing tables and functions are reported when
    the VIEW is used in a query.


<li>The query planner is now able to use [partial indexes] that contain
    AND-connected terms in the WHERE clause.
<li>The sqlite3_analyzer.exe utility is updated to report the depth of
    each btree and to show the average fanout for indexes and 
    WITHOUT ROWID tables.
<li>Enhance the [dbstat virtual table] so that it can be used as a
    [table-valued functions] where the argument is the schema to be







>






<



>
>







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
  global nChng aChng
  set aChng($nChng) [list $date $desc $options]
  incr nChng
}

chng {2015-11-01 (3.8.12)} {
<p><b>New Features And Enhancements:</b>
<li>Added [the json1 extension] module in the source tree.
<li>The [CREATE VIEW] statement now accepts an optional list of
    column names following the view name.
<li>Added support for [indexes on expressions].
<li>Added support for [table-valued functions] in the FROM clause of a
    [SELECT] statement.
<li>Added support for [eponymous virtual tables].

<li>A [VIEW] may now reference undefined tables and functions when
    initially created.  Missing tables and functions are reported when
    the VIEW is used in a query.
<li>Added the [sqlite3_value_subtype()] and [sqlite3_result_subtype()]
    interfaced (used by [the json1 extension]).
<li>The query planner is now able to use [partial indexes] that contain
    AND-connected terms in the WHERE clause.
<li>The sqlite3_analyzer.exe utility is updated to report the depth of
    each btree and to show the average fanout for indexes and 
    WITHOUT ROWID tables.
<li>Enhance the [dbstat virtual table] so that it can be used as a
    [table-valued functions] where the argument is the schema to be
Added pages/expridx.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
146
<tcl>hd_keywords {indexes on expressions} {Indexes On Expressions}</tcl>
<title>Indexes On Expressions</title>

<h1>Indexes On Expressions</h1>

<p>
Normally, an SQL index references columns of a table.  But an index
can also be formed on expressions involving table columns.

<p>
As an example, consider the following table that tracks
dollar-amount changes on various "accounts":

<blockquote><pre>
CREATE TABLE account_change(
  chng_id INTEGER PRIMARY KEY,
  acct_no INTEGER REFERENCES account,
  location INTEGER REFERENCES locations,
  amt INTEGER,  -- in cents
  authority TEXT,
  comment TEXT
);
CREATE INDEX acctchng_magnitude ON account_change(acct_no, abs(amt));
</pre></blockquote>

<p>
Each entry in the account_change table records a deposit or a withdrawl
into an account.  Deposits have a positive "amt" and withdrawls have
a negative "amt".

<p>
The acctchng_magnitude index is over the account number ("acct_no") and
on the absolute value of the amount.  This index allows one to do 
efficient queries over the magnitude of a change to the account.
For example, to list all changes to account number $xyz that are
more than $100.00, one can say:


<blockquote><pre>
SELECT * FROM account_change WHERE acct_no=$xyz AND abs(amt)>=10000;
</pre></blockquote>

<p>
Or, to list all changes to one particular account ($xyz) in order of
decreasing magnitude, one can write:

<blockquote><pre>
SELECT * FROM account_change WHERE acct_no=$xyz
 ORDER BY abs(amt) DESC;
</pre></blockquote>

<p>
Both of the above example queries would work fine without the
acctchng_magnitude index.
The acctchng_magnitude index index merely helps the queries to run
faster, especially on databases where there are many entries in
the table for each account.

<h2>How To Use Indexes On Expressions</h2>

<p>
Use a [CREATE INDEX] statement to create a new index on one or more
expressions just like you would to create an index on columns.  The only
difference is that expressions are listed as the elements to be indexed
rather than column names.

<p>
The SQLite query planner will consider using an index on an expression
when the expression that is indexed appears in the WHERE clause or in
the ORDER BY clause of a query, <i>exactly</i> as it is written in the
CREATE INDEX statement.  The query planner does not do algebra.  In order
to match WHERE clause constraints and ORDER BY terms to indexes, SQLite
requires that the expressions be the same, except for minor syntactic
differences such as white-space changes.  So if you have:

<blockquote><pre>
CREATE TABLE t2(x,y,z);
CREATE INDEX t2xy ON t2(x+y);
</pre></blockquote>

<p>
And then you run the query:

<blockquote><pre>
SELECT * FROM t2 WHERE y+x=22;
</pre></blockquote>

<p>
Then the index will <u>not</u> be used because 
the expression on the CREATE INDEX
statement (x+y) is not the same as the expression as it appears in the 
query (y+x).  The two expressions might be mathematically equivalent, but
the SQLite query planner insists that they be the same, not merely
equivalent.  Consider rewriting the query thusly:

<blockquote><pre>
SELECT * FROM t2 WHERE x+y=22;
</pre></blockquote>

<p>
This second query will likely use the index because now the expression
in the WHERE clause (x+y) matches the expression in the index exactly.


<h2>Restrictions</h2>

<p>
There are certain reasonable restrictions on expressions that appear in
CREATE INDEX statements:

<ol>
<li><p>
Expressions in CREATE INDEX statements
may only refer to columns of the table being indexed, not to
columns in other tables.

<li><p>
Expressions in CREATE INDEX statmeent
may contain function calls, but only to functions whose output
is always determined completely by its input parameters (a.k.a.:
"deterministic" functions).  Obviously, functions like [random()] will not
work well in an index.  But also functions like [sqlite_version()], though
they are constant across any one database connection, are not constant
across the life of the underlying database file, and hence may not be
used in a CREATE INDEX statement.

<p>
Note that [application-defined SQL functions] are by default considered
non-deterministic and may not be used in a CREATE INDEX statement unless
the [SQLITE_DETERMINISTIC] flag is used when the function is registered.

<li><p>
Expressions in CREATE INDEX statements may not use subqueries.

<li><p>
Expressions may only be used in CREATE INDEX statements, not within
[UNIQUE] or [PRIMARY KEY] constraints within the [CREATE TABLE] statement.
</ol>


<h2>Compatibility</h2>

<p>
The ability to index expressions was added to SQLite with 
[version 3.8.12] in October of 2015.  A database that uses an index on
expressions will not be usable by earlier versions of SQLite.
Changes to pages/lang.in.
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787


788
789
790
791
792
793
794
or expression 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>

<tcl>hd_fragment indexexpr {indexes on expressions}</tcl>
<p>^Expressions in an index may not reference other tables
and may not use subqueries nor functions whose result might
change (ex: [random()] or [sqlite_version()]).
^Expressions in an index may only refer to columns in the table
that is being indexed.
Indexes on expression will not work with versions of SQLite prior
to [version 3.8.12].



<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 the value set by
[sqlite3_limit]([SQLITE_LIMIT_COLUMN],...).)^</p>

<tcl>hd_fragment uniqueidx {unique index}</tcl>







|







>
>







773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
or expression 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>

<tcl>hd_fragment indexexpr</tcl>
<p>^Expressions in an index may not reference other tables
and may not use subqueries nor functions whose result might
change (ex: [random()] or [sqlite_version()]).
^Expressions in an index may only refer to columns in the table
that is being indexed.
Indexes on expression will not work with versions of SQLite prior
to [version 3.8.12].
See the [Indexes On Expressions] document for additional information
about using general expressions in CREATE INDEX statements.

<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 the value set by
[sqlite3_limit]([SQLITE_LIMIT_COLUMN],...).)^</p>

<tcl>hd_fragment uniqueidx {unique index}</tcl>