summaryrefslogtreecommitdiffstats
path: root/www/expridx.html
blob: 68586902ee260cdb5eea04de4e0884a85bf6ef42 (plain)
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
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
<!DOCTYPE html>
<html><head>
<meta name="viewport" content="width=device-width, initial-scale=1.0">
<meta http-equiv="content-type" content="text/html; charset=UTF-8">
<link href="sqlite.css" rel="stylesheet">
<title>Indexes On Expressions</title>
<!-- path= -->
</head>
<body>
<div class=nosearch>
<a href="index.html">
<img class="logo" src="images/sqlite370_banner.gif" alt="SQLite" border="0">
</a>
<div><!-- IE hack to prevent disappearing logo --></div>
<div class="tagline desktoponly">
Small. Fast. Reliable.<br>Choose any three.
</div>
<div class="menu mainmenu">
<ul>
<li><a href="index.html">Home</a>
<li class='mobileonly'><a href="javascript:void(0)" onclick='toggle_div("submenu")'>Menu</a>
<li class='wideonly'><a href='about.html'>About</a>
<li class='desktoponly'><a href="docs.html">Documentation</a>
<li class='desktoponly'><a href="download.html">Download</a>
<li class='wideonly'><a href='copyright.html'>License</a>
<li class='desktoponly'><a href="support.html">Support</a>
<li class='desktoponly'><a href="prosupport.html">Purchase</a>
<li class='search' id='search_menubutton'>
<a href="javascript:void(0)" onclick='toggle_search()'>Search</a>
</ul>
</div>
<div class="menu submenu" id="submenu">
<ul>
<li><a href='about.html'>About</a>
<li><a href='docs.html'>Documentation</a>
<li><a href='download.html'>Download</a>
<li><a href='support.html'>Support</a>
<li><a href='prosupport.html'>Purchase</a>
</ul>
</div>
<div class="searchmenu" id="searchmenu">
<form method="GET" action="search">
<select name="s" id="searchtype">
<option value="d">Search Documentation</option>
<option value="c">Search Changelog</option>
</select>
<input type="text" name="q" id="searchbox" value="">
<input type="submit" value="Go">
</form>
</div>
</div>
<script>
function toggle_div(nm) {
var w = document.getElementById(nm);
if( w.style.display=="block" ){
w.style.display = "none";
}else{
w.style.display = "block";
}
}
function toggle_search() {
var w = document.getElementById("searchmenu");
if( w.style.display=="block" ){
w.style.display = "none";
} else {
w.style.display = "block";
setTimeout(function(){
document.getElementById("searchbox").focus()
}, 30);
}
}
function div_off(nm){document.getElementById(nm).style.display="none";}
window.onbeforeunload = function(e){div_off("submenu");}
/* Disable the Search feature if we are not operating from CGI, since */
/* Search is accomplished using CGI and will not work without it. */
if( !location.origin || !location.origin.match || !location.origin.match(/http/) ){
document.getElementById("search_menubutton").style.display = "none";
}
/* Used by the Hide/Show button beside syntax diagrams, to toggle the */
function hideorshow(btn,obj){
var x = document.getElementById(obj);
var b = document.getElementById(btn);
if( x.style.display!='none' ){
x.style.display = 'none';
b.innerHTML='show';
}else{
x.style.display = '';
b.innerHTML='hide';
}
return false;
}
var antiRobot = 0;
function antiRobotGo(){
if( antiRobot!=3 ) return;
antiRobot = 7;
var j = document.getElementById("mtimelink");
if(j && j.hasAttribute("data-href")) j.href=j.getAttribute("data-href");
}
function antiRobotDefense(){
document.body.onmousedown=function(){
antiRobot |= 2;
antiRobotGo();
document.body.onmousedown=null;
}
document.body.onmousemove=function(){
antiRobot |= 2;
antiRobotGo();
document.body.onmousemove=null;
}
setTimeout(function(){
antiRobot |= 1;
antiRobotGo();
}, 100)
antiRobotGo();
}
antiRobotDefense();
</script>
<div class=fancy>
<div class=nosearch>
<div class="fancy_title">
Indexes On Expressions
</div>
</div>





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

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

</p><div class="codeblock"><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></div>

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

</p><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:


</p><div class="codeblock"><pre>SELECT * FROM account_change WHERE acct_no=$xyz AND abs(amt)>=10000;
</pre></div>

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

</p><div class="codeblock"><pre>SELECT * FROM account_change WHERE acct_no=$xyz
 ORDER BY abs(amt) DESC;
</pre></div>

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

</p><h1 id="how_to_use_indexes_on_expressions"><span>1. </span>How To Use Indexes On Expressions</h1>

<p>
Use a <a href="lang_createindex.html">CREATE INDEX</a> 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><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:

</p><div class="codeblock"><pre>CREATE TABLE t2(x,y,z);
CREATE INDEX t2xy ON t2(x+y);
</pre></div>

<p>
And then you run the query:

</p><div class="codeblock"><pre>SELECT * FROM t2 WHERE y+x=22;
</pre></div>

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

</p><div class="codeblock"><pre>SELECT * FROM t2 WHERE x+y=22;
</pre></div>

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


</p><h1 id="restrictions"><span>2. </span>Restrictions</h1>

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

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

</p></li><li><p>
Expressions in CREATE INDEX statements
may contain function calls, but only to functions whose output
is always determined completely by its input parameters (a.k.a.:
<a href="deterministic.html">deterministic functions</a>).  Obviously, functions like <a href="lang_corefunc.html#random">random()</a> will not
work well in an index.  But also functions like <a href="lang_corefunc.html#sqlite_version">sqlite_version()</a>, 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><p>
Note that <a href="appfunc.html">application-defined SQL functions</a> are by default considered
non-deterministic and may not be used in a CREATE INDEX statement unless
the <a href="c3ref/c_deterministic.html#sqlitedeterministic">SQLITE_DETERMINISTIC</a> flag is used when the function is registered.

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

</p></li><li><p>
Expressions may only be used in CREATE INDEX statements, not within
<a href="lang_createtable.html#uniqueconst">UNIQUE</a> or <a href="lang_createtable.html#primkeyconst">PRIMARY KEY</a> constraints within the <a href="lang_createtable.html">CREATE TABLE</a> statement.
</p></li></ol>


<h1 id="compatibility"><span>3. </span>Compatibility</h1>

<p>
The ability to index expressions was added to SQLite with 
<a href="releaselog/3_9_0.html">version 3.9.0</a> (2015-10-14).  A database that uses an index on
expressions will not be usable by earlier versions of SQLite.
</p><p align="center"><small><i>This page last modified on  <a href="https://sqlite.org/docsrc/honeypot" id="mtimelink"  data-href="https://sqlite.org/docsrc/finfo/pages/expridx.in?m=918a2f1493">2023-02-11 20:57:33</a> UTC </small></i></p>