#!/usr/bin/env tclsh set testdir [file dirname $argv0] source $testdir/tester.tcl do_execsql_test subquery-inner-filter { select sub.loud_hat from ( select concat(name, '!!!') as loud_hat from products where name = 'hat' ) sub; } {hat!!!} do_execsql_test subquery-inner-filter-cte { with sub as ( select concat(name, '!!!') as loud_hat from products where name = 'hat' ) select sub.loud_hat from sub; } {hat!!!} do_execsql_test subquery-outer-filter { select sub.loud_hat from ( select concat(name, '!!!') as loud_hat from products ) sub where sub.loud_hat = 'hat!!!' } {hat!!!} do_execsql_test subquery-outer-filter-cte { with sub as ( select concat(name, '!!!') as loud_hat from products ) select sub.loud_hat from sub where sub.loud_hat = 'hat!!!' } {hat!!!} do_execsql_test subquery-without-alias { select loud_hat from ( select concat(name, '!!!') as loud_hat from products where name = 'hat' ); } {hat!!!} do_execsql_test subquery-without-alias-cte { with cte as ( select concat(name, '!!!') as loud_hat from products where name = 'hat' ) select loud_hat from cte; } {hat!!!} do_execsql_test subquery-no-alias-on-col { select price from ( select * from products where name = 'hat' ) } {79.0} do_execsql_test subquery-no-alias-on-col-cte { with cte as ( select * from products where name = 'hat' ) select price from cte } {79.0} do_execsql_test subquery-no-alias-on-col-named { select price from ( select price from products where name = 'hat' ) } {79.0} do_execsql_test subquery-no-alias-on-col-named-cte { with cte as ( select price from products where name = 'hat' ) select price from cte } {79.0} do_execsql_test subquery-select-star { select * from ( select price, price + 1.0, name from products where name = 'hat' ) } {79.0|80.0|hat} do_execsql_test subquery-select-star-cte { with cte as ( select price, price + 1.0, name from products where name = 'hat' ) select * from cte } {79.0|80.0|hat} do_execsql_test subquery-select-table-star { select sub.* from ( select price, price + 1.0, name from products where name = 'hat' ) sub } {79.0|80.0|hat} do_execsql_test subquery-select-table-star-cte { with sub as ( select price, price + 1.0, name from products where name = 'hat' ) select sub.* from sub } {79.0|80.0|hat} do_execsql_test nested-subquery { select sub.loudest_hat from ( select upper(nested_sub.loud_hat) as loudest_hat from ( select concat(name, '!!!') as loud_hat from products where name = 'hat' ) nested_sub ) sub; } {HAT!!!} do_execsql_test nested-subquery-cte { with nested_sub as ( select concat(name, '!!!') as loud_hat from products where name = 'hat' ), sub as ( select upper(nested_sub.loud_hat) as loudest_hat from nested_sub ) select sub.loudest_hat from sub; } {HAT!!!} do_execsql_test subquery-orderby-limit { select upper(sub.loud_name) as loudest_name from ( select concat(name, '!!!') as loud_name from products order by name limit 3 ) sub; } {ACCESSORIES!!! BOOTS!!! CAP!!!} do_execsql_test subquery-orderby-limit-cte { with sub as ( select concat(name, '!!!') as loud_name from products order by name limit 3 ) select upper(sub.loud_name) as loudest_name from sub; } {ACCESSORIES!!! BOOTS!!! CAP!!!} do_execsql_test table-join-subquery { select sub.product_name, p.name from products p join ( select name as product_name from products ) sub on p.name = sub.product_name where p.name = 'hat' } {hat|hat} do_execsql_test table-join-subquery-cte { with sub as ( select name as product_name from products ) select sub.product_name, p.name from products p join sub on p.name = sub.product_name where p.name = 'hat' } {hat|hat} do_execsql_test subquery-join-table { select sub.product_name, p.name from ( select name as product_name from products ) sub join products p on sub.product_name = p.name where sub.product_name = 'hat' } {hat|hat} do_execsql_test subquery-join-table-cte { with sub as ( select name as product_name from products ) select sub.product_name, p.name from sub join products p on sub.product_name = p.name where sub.product_name = 'hat' } {hat|hat} do_execsql_test subquery-join-subquery { select sub1.sus_name, sub2.truthful_name from ( select name as sus_name from products where name = 'cap' ) sub1 join ( select concat('no ', name) as truthful_name from products where name = 'cap' ) sub2; } {"cap|no cap"} do_execsql_test subquery-join-subquery-cte { with sub1 as ( select name as sus_name from products where name = 'cap' ), sub2 as ( select concat('no ', name) as truthful_name from products where name = 'cap' ) select sub1.sus_name, sub2.truthful_name from sub1 join sub2; } {"cap|no cap"} do_execsql_test select-star-table-subquery { select * from products p join ( select name, price from products where name = 'hat' ) sub on p.name = sub.name; } {1|hat|79.0|hat|79.0} do_execsql_test select-star-table-subquery-cte { with sub as ( select name, price from products where name = 'hat' ) select * from products p join sub on p.name = sub.name; } {1|hat|79.0|hat|79.0} do_execsql_test select-star-subquery-table { select * from ( select name, price from products where name = 'hat' ) sub join products p on sub.name = p.name; } {hat|79.0|1|hat|79.0} do_execsql_test select-star-subquery-table-cte { with sub as ( select name, price from products where name = 'hat' ) select * from sub join products p on sub.name = p.name; } {hat|79.0|1|hat|79.0} do_execsql_test select-star-subquery-subquery { select * from ( select name, price from products where name = 'hat' ) sub1 join ( select price from products where name = 'hat' ) sub2 on sub1.price = sub2.price; } {hat|79.0|79.0} do_execsql_test select-star-subquery-subquery-cte { with sub1 as ( select name, price from products where name = 'hat' ), sub2 as ( select price from products where name = 'hat' ) select * from sub1 join sub2 on sub1.price = sub2.price; } {hat|79.0|79.0} do_execsql_test subquery-inner-grouping { select is_jennifer, person_count from ( select first_name = 'Jennifer' as is_jennifer, count(1) as person_count from users group by first_name = 'Jennifer' ) order by person_count asc } {1|151 0|9849} do_execsql_test subquery-inner-grouping-cte { with cte as ( select first_name = 'Jennifer' as is_jennifer, count(1) as person_count from users group by first_name = 'Jennifer' ) select is_jennifer, person_count from cte order by person_count asc } {1|151 0|9849} do_execsql_test subquery-outer-grouping { select is_jennifer, count(1) as person_count from ( select first_name = 'Jennifer' as is_jennifer from users ) group by is_jennifer order by count(1) asc } {1|151 0|9849} do_execsql_test subquery-outer-grouping-cte { with cte as ( select first_name = 'Jennifer' as is_jennifer from users ) select is_jennifer, count(1) as person_count from cte group by is_jennifer order by count(1) asc } {1|151 0|9849} do_execsql_test subquery-join-using-with-outer-limit { SELECT p.name, sub.funny_name FROM products p JOIN ( select id, concat(name, '-lol') as funny_name from products ) sub USING (id) LIMIT 3; } {"hat|hat-lol cap|cap-lol shirt|shirt-lol"} do_execsql_test subquery-join-using-with-outer-limit-cte { WITH sub AS ( select id, concat(name, '-lol') as funny_name from products ) SELECT p.name, sub.funny_name FROM products p JOIN sub USING (id) LIMIT 3; } {"hat|hat-lol cap|cap-lol shirt|shirt-lol"} do_execsql_test subquery-join-using-with-inner-limit { SELECT p.name, sub.funny_name FROM products p JOIN ( select id, concat(name, '-lol') as funny_name from products limit 3 ) sub USING (id); } {"hat|hat-lol cap|cap-lol shirt|shirt-lol"} do_execsql_test subquery-join-using-with-inner-limit-cte { WITH sub AS ( select id, concat(name, '-lol') as funny_name from products limit 3 ) SELECT p.name, sub.funny_name FROM products p JOIN sub USING (id); } {"hat|hat-lol cap|cap-lol shirt|shirt-lol"} do_execsql_test subquery-join-using-with-both-limits { SELECT p.name, sub.funny_name FROM products p JOIN ( select id, concat(name, '-lol') as funny_name from products limit 3 ) sub USING (id) LIMIT 2; } {"hat|hat-lol cap|cap-lol"} do_execsql_test subquery-join-using-with-both-limits-cte { WITH sub AS ( select id, concat(name, '-lol') as funny_name from products limit 3 ) SELECT p.name, sub.funny_name FROM products p JOIN sub USING (id) LIMIT 2; } {"hat|hat-lol cap|cap-lol"} do_execsql_test subquery-containing-join { select foo, bar from ( select p.name as foo, u.first_name as bar from products p join users u using (id) ) limit 3; } {hat|Jamie cap|Cindy shirt|Tommy} do_execsql_test subquery-containing-join-cte { with cte as ( select p.name as foo, u.first_name as bar from products p join users u using (id) ) select foo, bar from cte limit 3; } {hat|Jamie cap|Cindy shirt|Tommy} do_execsql_test subquery-ignore-unused-cte { with unused as (select last_name from users), sub as (select first_name from users where first_name = 'Jamie' limit 1) select * from sub; } {Jamie} # Test verifying that select distinct works (distinct ages are 1-100) do_execsql_test subquery-count-distinct-age { select count(1) from (select distinct age from users); } {100} # Test verifying that select distinct works for multiple columns, and across joins do_execsql_test subquery-count-distinct { select count(1) from ( select distinct first_name, name from users u join products p where u.id < 100 ); } {902} do_execsql_test subquery-count-all { select count(1) from ( select first_name, name from users u join products p where u.id < 100 ); } {1089} do_execsql_test_on_specific_db {:memory:} subquery-cte-available-in-arbitrary-depth { with cte as (select 1 as one) select onehundredandeleven+1 as onehundredandtwelve from ( with cte2 as (select 10 as ten) select onehundredandone+ten as onehundredandeleven from ( with cte3 as (select 100 as hundred) select one+hundred as onehundredandone from cte join cte3 ) join cte2 ); } {112} # WHERE CLAUSE SUBQUERIES # EXISTS/NOT EXISTS do_execsql_test_on_specific_db {:memory:} subquery-exists-basic { create table test(a); insert into test values (1); select * from test where exists (select 0); select * from test where not exists (select 0 where false); } {1 1} # Trivial example: get all users if there are any products do_execsql_test_on_specific_db {:memory:} subquery-exists-uncorrelated { create table products(id, name, price); create table users(id, name); insert into products values (1, 'hat', 50), (2, 'cap', 75), (3, 'shirt', 100); insert into users values (1, 'Alice'), (2, 'Bob'), (3, 'Charlie'); select * from users where exists (select 1 from products); } {1|Alice 2|Bob 3|Charlie} # Get all products when there are no users do_execsql_test_on_specific_db {:memory:} subquery-not-exists-uncorrelated { create table products(id, name, price); create table users(id, name); insert into products values (1, 'hat', 50), (2, 'cap', 75); select * from products where not exists (select 1 from users); } {1|hat|50 2|cap|75} # Get products that have a matching category do_execsql_test_on_specific_db {:memory:} subquery-exists-correlated { create table products(id, name, category_id); create table categories(id, name); insert into products values (1, 'hat', 10), (2, 'cap', 20), (3, 'shirt', 10); insert into categories values (10, 'Clothing'), (30, 'Electronics'); select * from products p where exists ( select * from categories c where c.id = p.category_id ); } {1|hat|10 3|shirt|10} # Get users who have no orders do_execsql_test_on_specific_db {:memory:} subquery-not-exists-correlated { create table users(id, name, age); create table orders(id, user_id, amount); insert into users values (1, 'Alice', 25), (2, 'Bob', 30), (3, 'Charlie', 35); insert into orders values (1, 1, 100), (2, 3, 200); select * from users u where not exists ( select * from orders o where o.user_id = u.id ); } {2|Bob|30} # Get products that belong to the 'Clothing' category do_execsql_test_on_specific_db {:memory:} subquery-exists-with-conditions { create table categories(id, name); create table products(id, name, price, category_id); insert into categories values (1, 'Clothing'), (2, 'Electronics'); insert into products values (1, 'hat', 50, 1), (2, 'cap', 25, 1), (3, 'macbook', 75, 2); select * from products p where exists ( select * from categories c where c.id = p.category_id and c.name = 'Clothing' ); } {1|hat|50|1 2|cap|25|1} # Get users who have products with high-rated reviews do_execsql_test_on_specific_db {:memory:} subquery-nested-exists { create table users(id, name); create table products(id, name, user_id); create table reviews(id, product_id, rating); insert into users values (1, 'Alice'), (2, 'Bob'); insert into products values (1, 'hat', 1), (2, 'cap', 2); insert into reviews values (1, 1, 5); select * from users u where exists ( select * from products p where p.user_id = u.id and exists ( select 1 from reviews r where r.product_id = p.id and r.rating >= 4 ) ); } {1|Alice} # Get products that have tags (none exist, so empty result) do_execsql_test_on_specific_db {:memory:} subquery-exists-empty-result { create table products(id, name); create table tags(product_id, tag); insert into products values (1, 'hat'), (2, 'cap'); select * from products p where exists ( select * from tags t where t.product_id = p.id ); } {} # Get users whose emails are not in the blocked list do_execsql_test_on_specific_db {:memory:} subquery-not-exists-all-match { create table users(id, email); create table blocked_emails(email); insert into users values (1, 'alice@test.com'), (2, 'bob@test.com'); insert into blocked_emails values ('spam@test.com'); select * from users u where not exists ( select * from blocked_emails b where b.email = u.email ); } {1|alice@test.com 2|bob@test.com} # SCALAR SUBQUERIES # Get products with price higher than average price do_execsql_test_on_specific_db {:memory:} subquery-scalar-comparison { create table products(id, name, price); insert into products values (1, 'hat', 50), (2, 'cap', 25), (3, 'jacket', 75); select * from products where price >= ( select avg(price) from products ); } {1|hat|50 3|jacket|75} # Get users with the highest score do_execsql_test_on_specific_db {:memory:} subquery-scalar-max { create table users(id, name, score); insert into users values (1, 'Alice', 85), (2, 'Bob', 92), (3, 'Charlie', 92); select * from users where score = ( select max(score) from users ); } {2|Bob|92 3|Charlie|92} # (x,y) IN SUBQUERIES # Get products from specific categories using IN do_execsql_test_on_specific_db {:memory:} subquery-in-single-column { create table products(id, name, category_id); create table categories(id, name); insert into categories values (1, 'Clothing'), (2, 'Electronics'), (3, 'Books'); insert into products values (1, 'hat', 1), (2, 'laptop', 2), (3, 'novel', 3), (4, 'cap', 1); select * from products where category_id in ( select id from categories where name in ('Clothing', 'Electronics') ); } {1|hat|1 2|laptop|2 4|cap|1} # Get products NOT in discontinued categories do_execsql_test_on_specific_db {:memory:} subquery-not-in-single-column { create table products(id, name, category_id); create table discontinued_categories(category_id); insert into products values (1, 'hat', 1), (2, 'laptop', 2), (3, 'book', 3); insert into discontinued_categories values (2); select * from products where category_id not in ( select category_id from discontinued_categories ); } {1|hat|1 3|book|3} # Get order items matching specific product-quantity combinations do_execsql_test_on_specific_db {:memory:} subquery-in-multiple-columns { create table order_items(order_id, product_id, quantity); create table special_offers(product_id, min_quantity); insert into order_items values (1, 10, 5), (2, 20, 3), (3, 10, 2), (4, 30, 1); insert into special_offers values (10, 5), (20, 3); select * from order_items where (product_id, quantity) in ( select product_id, min_quantity from special_offers ); } {1|10|5 2|20|3} # Get users whose (name, age) combination is not in the restricted list do_execsql_test_on_specific_db {:memory:} subquery-not-in-multiple-columns { create table users(id, name, age); create table restricted_profiles(name, age); insert into users values (1, 'Alice', 25), (2, 'Bob', 30), (3, 'Charlie', 25); insert into restricted_profiles values ('Bob', 30); select * from users where (name, age) not in ( select name, age from restricted_profiles ); } {1|Alice|25 3|Charlie|25}