Files
turso/testing/partial_idx.test
2025-09-20 14:38:49 -04:00

233 lines
11 KiB
Tcl
Executable File

#!/usr/bin/env tclsh
set testdir [file dirname $argv0]
source $testdir/tester.tcl
source $testdir/sqlite3/tester.tcl
do_execsql_test_on_specific_db {:memory:} partial-index-unique-basic {
CREATE TABLE users (id INTEGER PRIMARY KEY, email TEXT, status TEXT);
CREATE UNIQUE INDEX idx_active_email ON users(email) WHERE status = 'active';
INSERT INTO users VALUES (1, 'user@test.com', 'active');
INSERT INTO users VALUES (2, 'user@test.com', 'inactive');
INSERT INTO users VALUES (3, 'user@test.com', 'deleted');
SELECT id, email, status FROM users ORDER BY id;
} {1|user@test.com|active
2|user@test.com|inactive
3|user@test.com|deleted}
do_execsql_test_in_memory_error_content partial-index-unique-violation {
CREATE TABLE users (id INTEGER PRIMARY KEY, email TEXT, status TEXT);
CREATE UNIQUE INDEX idx_active_email ON users(email) WHERE status = 'active';
INSERT INTO users VALUES (1, 'user@test.com', 'active');
INSERT INTO users VALUES (2, 'user@test.com', 'inactive');
INSERT INTO users VALUES (3, 'user@test.com', 'deleted');
INSERT INTO users VALUES (4, 'user@test.com', 'active');
} {UNIQUE constraint failed: idx_active_email.email (19)}
do_execsql_test_on_specific_db {:memory:} partial-index-expression-where {
CREATE TABLE products (id INTEGER PRIMARY KEY, sku TEXT, price INTEGER);
CREATE UNIQUE INDEX idx_expensive ON products(sku) WHERE price > 100;
INSERT INTO products VALUES (1, 'ABC123', 50);
INSERT INTO products VALUES (2, 'ABC123', 150);
INSERT INTO products VALUES (3, 'XYZ789', 200);
INSERT INTO products VALUES (4, 'ABC123', 75);
SELECT id, sku, price FROM products ORDER BY id;
} {1|ABC123|50
2|ABC123|150
3|XYZ789|200
4|ABC123|75}
do_execsql_test_in_memory_error_content partial-index-expensive-violation {
CREATE TABLE products (id INTEGER PRIMARY KEY, sku TEXT, price INTEGER);
CREATE UNIQUE INDEX idx_expensive ON products(sku) WHERE price > 100;
INSERT INTO products VALUES (1, 'ABC123', 50);
INSERT INTO products VALUES (2, 'ABC123', 150);
INSERT INTO products VALUES (3, 'XYZ789', 200);
INSERT INTO products VALUES (4, 'ABC123', 75);
INSERT INTO products VALUES (5, 'ABC123', 250);
-- should fail with unique sku where price > 100
} {UNIQUE constraint failed: idx_expensive.sku (19)}
do_execsql_test_in_memory_error_content partial-index-expensive-violation-update {
CREATE TABLE products (id INTEGER PRIMARY KEY, sku TEXT, price INTEGER);
CREATE UNIQUE INDEX idx_expensive ON products(sku) WHERE price > 100;
INSERT INTO products VALUES (1, 'ABC123', 50);
INSERT INTO products VALUES (2, 'ABC123', 150);
INSERT INTO products VALUES (3, 'XYZ789', 200);
INSERT INTO products VALUES (4, 'ABC123', 75);
UPDATE products SET price = 300 WHERE id = 1;
-- should fail with unique sku where price > 100
} {UNIQUE constraint failed: products.sku (19)}
do_execsql_test_on_specific_db {:memory:} partial-index-null-where {
CREATE TABLE items (id INTEGER PRIMARY KEY, code TEXT, category TEXT);
CREATE UNIQUE INDEX idx_categorized ON items(code) WHERE category IS NOT NULL;
INSERT INTO items VALUES (1, 'ITEM1', 'electronics');
INSERT INTO items VALUES (2, 'ITEM1', NULL);
INSERT INTO items VALUES (3, 'ITEM1', NULL);
INSERT INTO items VALUES (4, 'ITEM2', 'books');
SELECT id, code, category FROM items ORDER BY id;
} {1|ITEM1|electronics
2|ITEM1|
3|ITEM1|
4|ITEM2|books}
do_execsql_test_in_memory_error_content partial-index-function-where {
CREATE TABLE docs (id INTEGER PRIMARY KEY, title TEXT);
CREATE UNIQUE INDEX idx_lower_title ON docs(title) WHERE LOWER(title) = title;
INSERT INTO docs VALUES (1, 'lowercase');
INSERT INTO docs VALUES (2, 'UPPERCASE');
INSERT INTO docs VALUES (3, 'lowercase');
} {UNIQUE constraint failed: idx_lower_title.title (19)}
do_execsql_test_on_specific_db {:memory:} partial-index-multiple {
CREATE TABLE tasks (id INTEGER PRIMARY KEY, name TEXT, priority INTEGER, status TEXT);
CREATE UNIQUE INDEX idx_urgent ON tasks(name) WHERE priority = 1;
CREATE UNIQUE INDEX idx_completed ON tasks(name) WHERE status = 'done';
INSERT INTO tasks VALUES (1, 'task1', 1, 'open');
INSERT INTO tasks VALUES (2, 'task1', 2, 'open');
INSERT INTO tasks VALUES (3, 'task1', 3, 'done');
INSERT INTO tasks VALUES (4, 'task2', 1, 'done');
SELECT id, name, priority, status FROM tasks ORDER BY id;
} {1|task1|1|open
2|task1|2|open
3|task1|3|done
4|task2|1|done}
do_execsql_test_in_memory_error_content partial-index-function-where {
CREATE TABLE tasks (id INTEGER PRIMARY KEY, name TEXT, priority INTEGER, status TEXT);
CREATE UNIQUE INDEX idx_urgent ON tasks(name) WHERE priority = 1;
CREATE UNIQUE INDEX idx_completed ON tasks(name) WHERE status = 'done';
INSERT INTO tasks VALUES (1, 'task1', 1, 'open');
INSERT INTO tasks VALUES (2, 'task1', 2, 'open');
INSERT INTO tasks VALUES (3, 'task1', 3, 'done');
INSERT INTO tasks VALUES (4, 'task2', 1, 'done');
INSERT INTO tasks VALUES (5, 'task1', 1, 'pending');
-- should fail for unique name where priority = 1
} {UNIQUE constraint failed: idx_urgent.name (19)}
do_execsql_test_in_memory_error_content partial-index-function-where-2 {
CREATE TABLE tasks (id INTEGER PRIMARY KEY, name TEXT, priority INTEGER, status TEXT);
CREATE UNIQUE INDEX idx_urgent ON tasks(name) WHERE priority = 1;
CREATE UNIQUE INDEX idx_completed ON tasks(name) WHERE status = 'done';
INSERT INTO tasks VALUES (1, 'task1', 1, 'open');
INSERT INTO tasks VALUES (2, 'task1', 2, 'open');
INSERT INTO tasks VALUES (3, 'task1', 3, 'done');
INSERT INTO tasks VALUES (4, 'task2', 1, 'done');
INSERT INTO tasks VALUES (6, 'task1', 2, 'done');
-- should fail for unique name where status = 'done'
} {UNIQUE constraint failed: idx_completed.name (19)}
do_execsql_test_on_specific_db {:memory:} partial-index-update-rowid {
CREATE TABLE rowid_test (id INTEGER PRIMARY KEY, val TEXT, flag INTEGER);
CREATE UNIQUE INDEX idx_flagged ON rowid_test(val) WHERE flag = 1;
INSERT INTO rowid_test VALUES (1, 'test', 1);
INSERT INTO rowid_test VALUES (2, 'test', 0);
UPDATE rowid_test SET id = 10 WHERE id = 1;
SELECT id, val, flag FROM rowid_test ORDER BY id;
} {2|test|0
10|test|1}
do_execsql_test_in_memory_error_content partial-index-update-complex {
CREATE TABLE complex (id INTEGER PRIMARY KEY, a TEXT, b INTEGER, c TEXT);
CREATE UNIQUE INDEX idx_complex ON complex(a) WHERE b > 10 AND c = 'active';
INSERT INTO complex VALUES (1, 'dup', 5, 'active');
INSERT INTO complex VALUES (2, 'dup', 15, 'inactive');
INSERT INTO complex VALUES (3, 'dup', 15, 'active');
INSERT INTO complex VALUES (4, 'dup', 20, 'active');
} {UNIQUE constraint failed: idx_complex.a (19)}
do_execsql_test_on_specific_db {:memory:} partial-index-delete {
CREATE TABLE products (id INTEGER PRIMARY KEY, sku TEXT, price INTEGER);
CREATE UNIQUE INDEX idx_expensive ON products(sku) WHERE price > 100;
INSERT INTO products VALUES (1, 'ABC123', 50);
INSERT INTO products VALUES (2, 'ABC123', 150);
INSERT INTO products VALUES (3, 'XYZ789', 200);
INSERT INTO products VALUES (4, 'ABC123', 75);
DELETE FROM products WHERE price > 100;
INSERT INTO products VALUES (5, 'ABC123', 500);
INSERT INTO products VALUES (6, 'XYZ789', 600);
SELECT id, sku, price FROM products WHERE price > 100 ORDER BY id;
} {5|ABC123|500
6|XYZ789|600}
do_execsql_test_on_specific_db {:memory:} partial-index-delete-function-where {
CREATE TABLE func_del (id INTEGER PRIMARY KEY, name TEXT);
CREATE UNIQUE INDEX idx_lower ON func_del(name) WHERE LOWER(name) = name;
INSERT INTO func_del VALUES (1, 'lowercase');
INSERT INTO func_del VALUES (2, 'UPPERCASE');
INSERT INTO func_del VALUES (3, 'MixedCase');
DELETE FROM func_del WHERE LOWER(name) = name;
-- Should be able to insert lowercase now
INSERT INTO func_del VALUES (4, 'lowercase');
INSERT INTO func_del VALUES (5, 'another');
SELECT id, name FROM func_del ORDER BY id;
} {2|UPPERCASE
3|MixedCase
4|lowercase
5|another}
do_execsql_test_in_memory_error_content partial-index-delete-all {
CREATE TABLE del_all (id INTEGER PRIMARY KEY, val TEXT, flag INTEGER);
CREATE UNIQUE INDEX idx_all ON del_all(val) WHERE flag = 1;
INSERT INTO del_all VALUES (1, 'test', 1), (2, 'test', 0), (3, 'other', 1);
DELETE FROM del_all;
-- Should be able to insert anything now
INSERT INTO del_all VALUES (4, 'test', 1);
INSERT INTO del_all VALUES (5, 'test', 1);
} {UNIQUE constraint failed: idx_all.val (19)}
do_execsql_test_on_specific_db {:memory:} partial-index-delete-cascade-scenario {
CREATE TABLE parent_del (id INTEGER PRIMARY KEY, status TEXT);
CREATE TABLE child_del (id INTEGER PRIMARY KEY, parent_id INTEGER, name TEXT, active INTEGER);
CREATE UNIQUE INDEX idx_active_child ON child_del(name) WHERE active = 1;
INSERT INTO parent_del VALUES (1, 'active'), (2, 'inactive');
INSERT INTO child_del VALUES (1, 1, 'child1', 1);
INSERT INTO child_del VALUES (2, 1, 'child2', 1);
INSERT INTO child_del VALUES (3, 2, 'child1', 0);
-- Simulate cascade by deleting children of parent 1
DELETE FROM child_del WHERE parent_id = 1;
-- Should now allow these since active children are gone
INSERT INTO child_del VALUES (4, 2, 'child1', 1);
INSERT INTO child_del VALUES (5, 2, 'child2', 1);
SELECT COUNT(*) FROM child_del WHERE active = 1;
} {2}
do_execsql_test_on_specific_db {:memory:} partial-index-delete-null-where {
CREATE TABLE null_del (id INTEGER PRIMARY KEY, code TEXT, category TEXT);
CREATE UNIQUE INDEX idx_with_category ON null_del(code) WHERE category IS NOT NULL;
INSERT INTO null_del VALUES (1, 'CODE1', 'cat1');
INSERT INTO null_del VALUES (2, 'CODE1', NULL);
INSERT INTO null_del VALUES (3, 'CODE2', 'cat2');
INSERT INTO null_del VALUES (4, 'CODE1', NULL);
-- Delete the one with category
DELETE FROM null_del WHERE code = 'CODE1' AND category IS NOT NULL;
-- Should allow this now
INSERT INTO null_del VALUES (5, 'CODE1', 'cat3');
SELECT id, code, category FROM null_del WHERE code = 'CODE1' ORDER BY id;
} {2|CODE1|
4|CODE1|
5|CODE1|cat3}
do_execsql_test_on_specific_db {:memory:} partial-index-delete-complex-where {
CREATE TABLE complex_del (id INTEGER PRIMARY KEY, a INTEGER, b INTEGER, c TEXT);
CREATE UNIQUE INDEX idx_complex ON complex_del(c) WHERE a > 10 AND b < 20;
INSERT INTO complex_del VALUES (1, 15, 10, 'dup');
INSERT INTO complex_del VALUES (2, 5, 15, 'dup');
INSERT INTO complex_del VALUES (3, 15, 25, 'dup');
INSERT INTO complex_del VALUES (4, 20, 10, 'unique');
-- Delete the one entry that's actually in the partial index
DELETE FROM complex_del WHERE a > 10 AND b < 20;
-- Should now allow this since we deleted the conflicting entry
INSERT INTO complex_del VALUES (5, 12, 18, 'dup');
SELECT COUNT(*) FROM complex_del WHERE c = 'dup';
} {3}