mirror of
https://github.com/aljazceru/turso.git
synced 2026-01-19 08:04:19 +01:00
Merge '(core): Primary key index scans and single-column secondary index scans' from Jussi Saurio
This PR adds an index on `users.age` to `testing.db`, and support for indexed lookups. Only single-column ascending indexes are currently supported. This PR also gets rid of `Operator::Seekrowid` in favor of `Operator::Search` which handles all non-full-table-scan searches: 1. integer primary key (rowid) point queries 2. integer primary key index scans, and 3. secondary index scans. examples: ``` limbo> select first_name, age from users where age > 90 limit 10; Miranda|90 Sarah|90 Justin|90 Justin|90 John|90 Jeremy|90 Stephanie|90 Joshua|90 Jenny|90 Jennifer|90 limbo> explain query plan select first_name, age from users where age > 90 limit 10; QUERY PLAN `--TAKE 10 `--PROJECT first_name, age | `--SEARCH users USING INDEX age_idx limbo> explain select first_name, age from users where age > 90 limit 10; addr opcode p1 p2 p3 p4 p5 comment ---- ----------------- ---- ---- ---- ------------- -- ------- 0 Init 0 15 0 0 Start at 15 1 OpenReadAsync 0 2 0 0 table=users, root=2 2 OpenReadAwait 0 0 0 0 3 OpenReadAsync 1 274 0 0 table=age_idx, root=274 4 OpenReadAwait 0 0 0 0 5 Integer 90 1 0 0 r[1]=90 6 SeekGT 1 14 1 0 7 DeferredSeek 1 0 0 0 8 Column 0 1 2 0 r[2]=users.first_name 9 Column 0 9 3 0 r[3]=users.age 10 ResultRow 2 2 0 0 output=r[2..3] 11 DecrJumpZero 4 14 0 0 if (--r[4]==0) goto 14 12 NextAsync 1 0 0 0 13 NextAwait 1 7 0 0 14 Halt 0 0 0 0 15 Transaction 0 0 0 0 16 Integer 10 4 0 0 r[4]=10 17 Goto 0 1 0 0 ``` Sqlite version: ``` sqlite> explain select first_name, age from users where age > 90 limit 10; addr opcode p1 p2 p3 p4 p5 comment ---- ------------- ---- ---- ---- ------------- -- ------------- 0 Init 0 13 0 0 Start at 13 1 Integer 10 1 0 0 r[1]=10; LIMIT counter 2 OpenRead 0 2 0 10 0 root=2 iDb=0; users 3 OpenRead 1 274 0 k(2,,) 0 root=274 iDb=0; age_idx 4 Integer 90 2 0 0 r[2]=90 5 SeekGT 1 12 2 1 0 key=r[2] 6 DeferredSeek 1 0 0 0 Move 0 to 1.rowid if needed 7 Column 0 1 3 0 r[3]= cursor 0 column 1 8 Column 1 0 4 0 r[4]= cursor 1 column 0 9 ResultRow 3 2 0 0 output=r[3..4] 10 DecrJumpZero 1 12 0 0 if (--r[1])==0 goto 12 11 Next 1 6 0 0 12 Halt 0 0 0 0 13 Transaction 0 0 3 0 1 usesStmtJournal=0 14 Goto 0 1 0 0 ``` --- ´Seek` instructions are also now supported for primary key rowid searches: ``` limbo> select id, first_name from users where id > 9995; 9996|Donald 9997|Ruth 9998|Dorothy 9999|Gina 10000|Nicole limbo> explain query plan select id, first_name from users where id > 9995; QUERY PLAN `--PROJECT id, first_name `--SEARCH users USING INTEGER PRIMARY KEY (rowid=?) limbo> explain select id, first_name from users where id > 9995; addr opcode p1 p2 p3 p4 p5 comment ---- ----------------- ---- ---- ---- ------------- -- ------- 0 Init 0 11 0 0 Start at 11 1 OpenReadAsync 0 2 0 0 table=users, root=2 2 OpenReadAwait 0 0 0 0 3 Integer 9995 1 0 0 r[1]=9995 4 SeekGT 0 10 1 0 5 RowId 0 2 0 0 r[2]=users.rowid 6 Column 0 1 3 0 r[3]=users.first_name 7 ResultRow 2 2 0 0 output=r[2..3] 8 NextAsync 0 0 0 0 9 NextAwait 0 5 0 0 10 Halt 0 0 0 0 11 Transaction 0 0 0 0 12 Goto 0 1 0 0 ``` sqlite: ``` sqlite> explain select id, first_name from users where id > 9995; addr opcode p1 p2 p3 p4 p5 comment ---- ------------- ---- ---- ---- ------------- -- ------------- 0 Init 0 8 0 0 Start at 8 1 OpenRead 0 2 0 2 0 root=2 iDb=0; users 2 SeekGT 0 7 1 0 key=r[1]; pk 3 Rowid 0 2 0 0 r[2]=users.rowid 4 Column 0 1 3 0 r[3]= cursor 0 column 1 5 ResultRow 2 2 0 0 output=r[2..3] 6 Next 0 3 0 0 7 Halt 0 0 0 0 8 Transaction 0 0 3 0 1 usesStmtJournal=0 9 Integer 9995 1 0 0 r[1]=9995 10 Goto 0 1 0 0 ``` --- More complex example with a join that uses both a rowid lookup and a secondary index scan: ``` limbo> explain query plan select u.first_name, p.name from users u join products p on u.id = p.id and u.age > 70; QUERY PLAN `--PROJECT u.first_name, p.name `--JOIN | |--SEARCH u USING INDEX age_idx | `--SEARCH p USING INTEGER PRIMARY KEY (rowid=?) limbo> explain select u.first_name, p.name from users u join products p on u.id = p.id and u.age > 70; addr opcode p1 p2 p3 p4 p5 comment ---- ----------------- ---- ---- ---- ------------- -- ------- 0 Init 0 18 0 0 Start at 18 1 OpenReadAsync 0 2 0 0 table=u, root=2 2 OpenReadAwait 0 0 0 0 3 OpenReadAsync 1 274 0 0 table=age_idx, root=274 4 OpenReadAwait 0 0 0 0 5 OpenReadAsync 2 3 0 0 table=p, root=3 6 OpenReadAwait 0 0 0 0 7 Integer 70 1 0 0 r[1]=70 8 SeekGT 1 17 1 0 9 DeferredSeek 1 0 0 0 10 RowId 0 2 0 0 r[2]=u.rowid 11 SeekRowid 2 2 15 0 if (r[2]!=p.rowid) goto 15 12 Column 0 1 3 0 r[3]=u.first_name 13 Column 2 1 4 0 r[4]=p.name 14 ResultRow 3 2 0 0 output=r[3..4] 15 NextAsync 1 0 0 0 16 NextAwait 1 9 0 0 17 Halt 0 0 0 0 18 Transaction 0 0 0 0 19 Goto 0 1 0 0 ``` sqlite: ``` sqlite> explain select u.first_name, p.name from users u join products p on u.id = p.id and u.age > 70; addr opcode p1 p2 p3 p4 p5 comment ---- ------------- ---- ---- ---- ------------- -- ------------- 0 Init 0 14 0 0 Start at 14 1 OpenRead 0 2 0 10 0 root=2 iDb=0; users 2 OpenRead 2 274 0 k(2,,) 0 root=274 iDb=0; age_idx 3 OpenRead 1 3 0 2 0 root=3 iDb=0; products 4 Integer 70 1 0 0 r[1]=70 5 SeekGT 2 13 1 1 0 key=r[1] 6 DeferredSeek 2 0 0 0 Move 0 to 2.rowid if needed 7 IdxRowid 2 2 0 0 r[2]=rowid; users.rowid 8 SeekRowid 1 12 2 0 intkey=r[2] 9 Column 0 1 3 0 r[3]= cursor 0 column 1 10 Column 1 1 4 0 r[4]= cursor 1 column 1 11 ResultRow 3 2 0 0 output=r[3..4] 12 Next 2 6 0 0 13 Halt 0 0 0 0 14 Transaction 0 0 3 0 1 usesStmtJournal=0 15 Goto 0 1 0 0 ``` Closes #350
This commit is contained in:
@@ -28,8 +28,8 @@ do_execsql_test select-total-text {
|
||||
} {0.0}
|
||||
|
||||
do_execsql_test select-limit {
|
||||
SELECT id FROM users LIMIT 1;
|
||||
} {1}
|
||||
SELECT typeof(id) FROM users LIMIT 1;
|
||||
} {integer}
|
||||
|
||||
do_execsql_test select-count {
|
||||
SELECT count(id) FROM users;
|
||||
|
||||
@@ -5,7 +5,7 @@ source $testdir/tester.tcl
|
||||
|
||||
do_execsql_test schema {
|
||||
.schema
|
||||
} {{CREATE TABLE users (
|
||||
} {"CREATE TABLE users (
|
||||
id INTEGER PRIMARY KEY,
|
||||
first_name TEXT,
|
||||
last_name TEXT,
|
||||
@@ -21,11 +21,12 @@ CREATE TABLE products (
|
||||
id INTEGER PRIMARY KEY,
|
||||
name TEXT,
|
||||
price REAL
|
||||
);}}
|
||||
);
|
||||
CREATE INDEX age_idx on users (age);"}
|
||||
|
||||
do_execsql_test schema-1 {
|
||||
.schema users
|
||||
} {{CREATE TABLE users (
|
||||
} {"CREATE TABLE users (
|
||||
id INTEGER PRIMARY KEY,
|
||||
first_name TEXT,
|
||||
last_name TEXT,
|
||||
@@ -36,7 +37,8 @@ do_execsql_test schema-1 {
|
||||
state TEXT,
|
||||
zipcode TEXT,
|
||||
age INTEGER
|
||||
);}}
|
||||
);
|
||||
CREATE INDEX age_idx on users (age);"}
|
||||
|
||||
do_execsql_test schema-2 {
|
||||
.schema products
|
||||
|
||||
@@ -200,3 +200,9 @@ Jamie||Edward}
|
||||
do_execsql_test left-join-constant-condition-true-inner-join-constant-condition-false {
|
||||
select u.first_name, p.name, u2.first_name from users u left join products as p on 1 join users u2 on 0 limit 5;
|
||||
} {}
|
||||
|
||||
do_execsql_test join-utilizing-both-seekrowid-and-secondary-index {
|
||||
select u.first_name, p.name from users u join products p on u.id = p.id and u.age > 70;
|
||||
} {Matthew|boots
|
||||
Nicholas|shorts
|
||||
Jamie|hat}
|
||||
@@ -44,8 +44,8 @@ do_execsql_test table-star {
|
||||
} {1|hat|79.0|hat}
|
||||
|
||||
do_execsql_test table-star-2 {
|
||||
select p.*, u.age from users u join products p limit 1;
|
||||
} {1|hat|79.0|94}
|
||||
select p.*, u.first_name from users u join products p on u.id = p.id limit 1;
|
||||
} {1|hat|79.0|Jamie}
|
||||
|
||||
do_execsql_test seekrowid {
|
||||
select * from users u where u.id = 5;
|
||||
|
||||
Binary file not shown.
@@ -92,24 +92,25 @@ do_execsql_test where-clause-no-table-constant-condition-false-7 {
|
||||
select 1 where 'hamburger';
|
||||
} {}
|
||||
|
||||
# this test functions as an assertion that the index on users.age is being used, since the results are ordered by age without an order by.
|
||||
do_execsql_test select-where-and {
|
||||
select first_name, age from users where first_name = 'Jamie' and age > 80
|
||||
} {Jamie|94
|
||||
} {Jamie|87
|
||||
Jamie|88
|
||||
Jamie|88
|
||||
Jamie|99
|
||||
Jamie|92
|
||||
Jamie|87
|
||||
Jamie|88
|
||||
Jamie|94
|
||||
Jamie|99
|
||||
}
|
||||
|
||||
do_execsql_test select-where-or {
|
||||
select first_name, age from users where first_name = 'Jamie' and age > 80
|
||||
} {Jamie|94
|
||||
} {Jamie|87
|
||||
Jamie|88
|
||||
Jamie|88
|
||||
Jamie|99
|
||||
Jamie|92
|
||||
Jamie|87
|
||||
Jamie|88
|
||||
Jamie|94
|
||||
Jamie|99
|
||||
}
|
||||
|
||||
do_execsql_test select-where-and-or {
|
||||
@@ -267,3 +268,44 @@ do_execsql_test where-complex-parentheses {
|
||||
select id, name from products where ((id = 5 and name = 'sweatshirt') or (id = 1 and name = 'hat')) and (name = 'sweatshirt' or name = 'hat') ORDER BY id;
|
||||
} {1|hat
|
||||
5|sweatshirt}
|
||||
|
||||
# regression test for primary key index behavior
|
||||
do_execsql_test where-id-index-seek-regression-test {
|
||||
select id from users where id > 9995;
|
||||
} {9996
|
||||
9997
|
||||
9998
|
||||
9999
|
||||
10000}
|
||||
|
||||
do_execsql_test where-id-index-seek-regression-test-2 {
|
||||
select count(1) from users where id > 0;
|
||||
} {10000}
|
||||
|
||||
# regression test for secondary index (users.age) behavior
|
||||
do_execsql_test where-age-index-seek-regression-test {
|
||||
select age from users where age >= 100 limit 20;
|
||||
} {100
|
||||
100
|
||||
100
|
||||
100
|
||||
100
|
||||
100
|
||||
100
|
||||
100
|
||||
100
|
||||
100
|
||||
100
|
||||
100
|
||||
100
|
||||
100
|
||||
100
|
||||
100
|
||||
100
|
||||
100
|
||||
100
|
||||
100}
|
||||
|
||||
do_execsql_test where-age-index-seek-regression-test-2 {
|
||||
select count(1) from users where age > 0;
|
||||
} {10000}
|
||||
|
||||
Reference in New Issue
Block a user