Skip to content

Commit

Permalink
Merge #45226
Browse files Browse the repository at this point in the history
45226: sql: refactor and improve testing for secondary indexes with families r=jordanlewis a=rohany

This PR moves TRACING based tests for secondary indexes
with column families out of logictest and moves them
into execbuilder.

Additionally, this PR adds some more test coverage
around secondary indexes with families.

Release note: None

Co-authored-by: Rohan Yadav <[email protected]>
  • Loading branch information
craig[bot] and rohany committed Feb 25, 2020
2 parents e6bd3bf + fe4da44 commit ca557e0
Show file tree
Hide file tree
Showing 2 changed files with 434 additions and 263 deletions.
341 changes: 78 additions & 263 deletions pkg/sql/logictest/testdata/logic_test/secondary_index_column_families
Original file line number Diff line number Diff line change
@@ -1,292 +1,107 @@
# LogicTest: local local-vec

# Test K/V operations on different types of indexes with column families.

statement ok
CREATE TABLE t1 (
x INT PRIMARY KEY, y INT, z INT, a INT, b INT,
FAMILY (x), FAMILY (y), FAMILY (z), FAMILY (a, b),
INDEX nonuniqueidx (y), UNIQUE INDEX uniqueidx (y),
INDEX nonuniqueidxstoring (y) STORING (z, a, b),
UNIQUE INDEX uniqueidxstoring (y) STORING (z, a, b)
)

# Ensure that inserts into each index look like we expect them to.
statement ok
SET TRACING=on,kv,results; INSERT INTO t1 VALUES (1, 1, 1, 1, 1); SET TRACING=off;

# Inserts into nonuniqueidx or uniqueidx (which don't store anything) should be a single kv pair of the old format.
query T
SELECT message FROM [SHOW KV TRACE FOR SESSION] WHERE
message LIKE 'InitPut /Table/53/2/%' OR
message LIKE 'InitPut /Table/53/3/%'
ORDER BY message
----
InitPut /Table/53/2/1/1/0 -> /BYTES/
InitPut /Table/53/3/1/0 -> /BYTES/0x89

# Inserts into nonuniqueidxstoring should generate 3 K/V pairs.
query T
SELECT message FROM [SHOW KV TRACE FOR SESSION] WHERE
message LIKE 'InitPut /Table/53/4/%'
ORDER BY message
----
InitPut /Table/53/4/1/1/0 -> /BYTES/
InitPut /Table/53/4/1/1/2/1 -> /TUPLE/3:3:Int/1
InitPut /Table/53/4/1/1/3/1 -> /TUPLE/4:4:Int/1/1:5:Int/1

# Inserts into uniqueidxstoring should generate 3 K/V pairs.
query T
SELECT message FROM [SHOW KV TRACE FOR SESSION] WHERE
message LIKE 'InitPut /Table/53/5/%'
ORDER BY message
----
InitPut /Table/53/5/1/0 -> /BYTES/0x89
InitPut /Table/53/5/1/2/1 -> /TUPLE/3:3:Int/1
InitPut /Table/53/5/1/3/1 -> /TUPLE/4:4:Int/1/1:5:Int/1

# Deletions should delete all k/v pairs for each index.
statement ok
SET TRACING=on,kv,results; DELETE FROM t1 WHERE x = 1; SET TRACING=off;

# Deletes on nonuniqueidx or uniqueidx (which don't store anything) should be a single kv pair of the old format.
query T
SELECT message FROM [SHOW KV TRACE FOR SESSION] WHERE
message LIKE 'Del /Table/53/2/%' OR
message LIKE 'Del /Table/53/3/%'
ORDER BY message
----
Del /Table/53/2/1/1/0
Del /Table/53/3/1/0

# Deletes on nonuniqueidxstoring should generate 3 K/V pairs.
query T
SELECT message FROM [SHOW KV TRACE FOR SESSION] WHERE
message LIKE 'Del /Table/53/4/%'
ORDER BY message
----
Del /Table/53/4/1/1/0
Del /Table/53/4/1/1/2/1
Del /Table/53/4/1/1/3/1

# Deletes on uniqueidxstoring should generate 3 K/V pairs.
query T
SELECT message FROM [SHOW KV TRACE FOR SESSION] WHERE
message LIKE 'Del /Table/53/5/%'
ORDER BY message
----
Del /Table/53/5/1/0
Del /Table/53/5/1/2/1
Del /Table/53/5/1/3/1

# Put some data back into the table.
# Ensure updates that remove a k/v pair succeed.
statement ok
INSERT INTO t1 VALUES (1, 1, 1, 1, 1)

# Selects (as of now) should scan all of the K/V pairs for each index.
query I
SET TRACING=on,kv,results;
SELECT y FROM t1@nonuniqueidx;
SET TRACING=off
----
1

query T
SELECT message FROM [SHOW KV TRACE FOR SESSION] WHERE
message LIKE 'fetched: /t1/nonuniqueidx/%'
----
fetched: /t1/nonuniqueidx/1/1 -> NULL

query I
SET TRACING=on,kv,results;
SELECT y FROM t1@uniqueidx;
SET TRACING=off
----
1

query T
SELECT message FROM [SHOW KV TRACE FOR SESSION] WHERE
message LIKE 'fetched: /t1/uniqueidx/%'
----
fetched: /t1/uniqueidx/1 -> /1

query IIIII
SET TRACING=on,kv,results;
SELECT * FROM t1@nonuniqueidxstoring;
SET TRACING=off
----
1 1 1 1 1

query T
SELECT message FROM [SHOW KV TRACE FOR SESSION] WHERE
message LIKE 'fetched: /t1/nonuniqueidxstoring/%'
----
fetched: /t1/nonuniqueidxstoring/1/1 -> NULL
fetched: /t1/nonuniqueidxstoring/1/1/z -> /1
fetched: /t1/nonuniqueidxstoring/1/1/a/b -> /1/1

query IIIII
SET TRACING=on,kv,results;
SELECT * FROM t1@uniqueidxstoring;
SET TRACING=off
----
1 1 1 1 1
CREATE TABLE t (
x INT PRIMARY KEY,
y INT,
z INT,
w INT,
INDEX i (y) STORING (z, w),
FAMILY (x), FAMILY (y), FAMILY (z), FAMILY (w)
);
INSERT INTO t VALUES (1, 2, 3, 4);
UPDATE t SET z = NULL, w = NULL WHERE y = 2

query T
SELECT message FROM [SHOW KV TRACE FOR SESSION] WHERE
message LIKE 'fetched: /t1/uniqueidxstoring/%'
query III
SELECT y, z, w FROM t@i WHERE y = 2
----
fetched: /t1/uniqueidxstoring/1 -> /1
fetched: /t1/uniqueidxstoring/1/z -> /1
fetched: /t1/uniqueidxstoring/1/a/b -> /1/1

2 NULL NULL

#Test some specific behavior with nulls on unique indexes.
# Test some cases around insert on conflict.
statement ok
INSERT INTO t1 VALUES (3, NULL, 3, 3, 3), (4, NULL, 4, 4, 4)

query IIIII
SET TRACING=on,kv,results;
SELECT * FROM t1@uniqueidxstoring ORDER BY x;
SET TRACING=off
----
1 1 1 1 1
3 NULL 3 3 3
4 NULL 4 4 4
DROP TABLE IF EXISTS t;
CREATE TABLE t (
x INT PRIMARY KEY,
y INT,
z STRING,
v INT,
UNIQUE INDEX i (y) STORING (z, v)
);
INSERT INTO t VALUES (1, 2, '3', 4), (5, 6, '7', 8);
INSERT INTO t VALUES (10, 2, '10', 10) ON CONFLICT (y) DO NOTHING

query T
SELECT message FROM [SHOW KV TRACE FOR SESSION] WHERE
message LIKE 'fetched: /t1/uniqueidxstoring/%'
ORDER BY message
query ITI rowsort
SELECT y, z, v FROM t@i
----
fetched: /t1/uniqueidxstoring/1 -> /1
fetched: /t1/uniqueidxstoring/1/a/b -> /1/1
fetched: /t1/uniqueidxstoring/1/z -> /1
fetched: /t1/uniqueidxstoring/NULL -> /3
fetched: /t1/uniqueidxstoring/NULL -> /4
fetched: /t1/uniqueidxstoring/NULL/a/b -> /3/3
fetched: /t1/uniqueidxstoring/NULL/a/b -> /4/4
fetched: /t1/uniqueidxstoring/NULL/z -> /3
fetched: /t1/uniqueidxstoring/NULL/z -> /4
2 3 4
6 7 8

# Ensure that updates delete and insert all K/V pairs for each index.
statement ok
SET TRACING=on,kv,results;
UPDATE t1 SET
x = 2, y = 2, z = 2, a = 2, b = 2
WHERE x = 1;
SET TRACING=off;
INSERT INTO t VALUES (10, 2, '10', 10) ON CONFLICT (y) DO UPDATE set x = 20, z = '20', v = 20 WHERE t.y = 2

# Updates on nonuniqueidx or uniqueidx (which don't store anything) should be a single kv pair of the old format.
query T
SELECT message FROM [SHOW KV TRACE FOR SESSION] WHERE
message LIKE 'Del /Table/53/2/%' OR
message LIKE 'InitPut /Table/53/2/%' OR
message LIKE 'Del /Table/53/3/%' OR
message LIKE 'InitPut /Table/53/3/%'
ORDER BY message
query ITI rowsort
SELECT y, z, v FROM t@i
----
Del /Table/53/2/1/1/0
Del /Table/53/3/1/0
InitPut /Table/53/2/2/2/0 -> /BYTES/
InitPut /Table/53/3/2/0 -> /BYTES/0x8a
2 20 20
6 7 8

# Updates on nonuniqueidxstoring should generate 3 K/V pairs.
query T
SELECT message FROM [SHOW KV TRACE FOR SESSION] WHERE
message LIKE 'Del /Table/53/4/%' OR
message LIKE 'InitPut /Table/53/4/%'
ORDER BY message
----
Del /Table/53/4/1/1/0
Del /Table/53/4/1/1/2/1
Del /Table/53/4/1/1/3/1
InitPut /Table/53/4/2/2/0 -> /BYTES/
InitPut /Table/53/4/2/2/2/1 -> /TUPLE/3:3:Int/2
InitPut /Table/53/4/2/2/3/1 -> /TUPLE/4:4:Int/2/1:5:Int/2

# Updates on uniqueidxstoring should generate 3 K/V pairs.
query T
SELECT message FROM [SHOW KV TRACE FOR SESSION] WHERE
message LIKE 'Del /Table/53/5/%' OR
message LIKE 'InitPut /Table/53/5/%'
ORDER BY message
----
Del /Table/53/5/1/0
Del /Table/53/5/1/2/1
Del /Table/53/5/1/3/1
InitPut /Table/53/5/2/0 -> /BYTES/0x8a
InitPut /Table/53/5/2/2/1 -> /TUPLE/3:3:Int/2
InitPut /Table/53/5/2/3/1 -> /TUPLE/4:4:Int/2/1:5:Int/2

# Regression for #42992.
# Test some cases around upsert.
statement ok
CREATE TABLE t42992 (x TIMESTAMP PRIMARY KEY, y INT, z INT, UNIQUE INDEX i (y) STORING (z), FAMILY (x), FAMILY (y), FAMILY (z))

statement ok
INSERT INTO t42992 VALUES (now(), NULL, 2)
DROP TABLE IF EXISTS t;
CREATE TABLE t (
x INT PRIMARY KEY,
y STRING,
z DECIMAL,
w INT,
FAMILY (y), FAMILY (z), FAMILY (x, w),
INDEX i (y) STORING (z, w)
);
INSERT INTO t VALUES (1, '2', 3.0, 4), (5, '6', 7.00, 8);
UPSERT INTO t VALUES (9, '10', 11.000, 12), (1, '3', 5.0, 16)

query II
SELECT y, z FROM t42992@i
query TTI rowsort
SELECT y, z, w FROM t@i
----
NULL 2

# Ensure that reads only scan the necessary k/v's.
3 5.0 16
6 7.00 8
10 11.000 12

# Test some cases around schema changes.
statement ok
DROP TABLE IF EXISTS t;
CREATE TABLE t (
x INT, y INT, z INT,
FAMILY (x), FAMILY (y), FAMILY (z),
UNIQUE INDEX i (x) STORING (y, z),
INDEX i2 (x) STORING (y, z)
x INT PRIMARY KEY,
y DECIMAL,
z INT,
w INT,
v INT
);
INSERT INTO t VALUES (1, 2, 3)
INSERT INTO t VALUES (1, 2, 3, 4, 5), (6, 7, 8, 9, 10), (11, 12, 13, 14, 15);
CREATE INDEX i ON t (y) STORING (z, w, v)

query I
SET TRACING=on,kv,results;
SELECT y FROM t@i WHERE x = 1;
SET TRACING=off
query TIII rowsort
SELECT y, z, w, v FROM t@i
----
2
2 3 4 5
7 8 9 10
12 13 14 15

# In this case, we scan only families 0 and 1.
# We don't really need family 0, but removing that
# from the needed families code is a further optimization.
query T
SELECT message FROM [SHOW KV TRACE FOR SESSION] WHERE
message LIKE 'Scan%'
ORDER BY message
----
Scan /Table/55/2/1/{0-1/2}

# Make sure that family splitting doesn't affect
# lookups when there are null values along the
# secondary index.
statement ok
INSERT INTO t VALUES (NULL, 3, 4)
DROP INDEX t@i

query I
SET TRACING=on,kv,results;
SELECT y FROM t@i WHERE x IS NULL;
SET TRACING=off
query ITIII rowsort
SELECT * FROM t
----
3
1 2 3 4 5
6 7 8 9 10
11 12 13 14 15

query T
SELECT message FROM [SHOW KV TRACE FOR SESSION] WHERE
message LIKE 'Scan%'
ORDER BY message
----
Scan /Table/55/2/{NULL-!NULL}
statement ok
ALTER TABLE t ADD COLUMN u INT DEFAULT (20) CREATE FAMILY new_fam;
CREATE INDEX i ON t (y) STORING (z, w, v, u)

# Ensure that updates only touch the changed column families.
query T
SET TRACING=on,kv,results;
UPDATE t SET y = 5 WHERE x = 1;
SET TRACING=off;
SELECT message FROM [SHOW KV TRACE FOR SESSION] WHERE
message LIKE 'CPut /Table/55/2%'
ORDER BY message
query TIIII rowsort
SELECT y, z, w, v, u FROM t@i
----
CPut /Table/55/2/1/1/1 -> /TUPLE/2:2:Int/5 (replacing raw_bytes:"\000\000\000\000\n#\004" timestamp:<> , if exists)
2 3 4 5 20
7 8 9 10 20
12 13 14 15 20
Loading

0 comments on commit ca557e0

Please sign in to comment.