1*c5c4113dSnw141292 2*c5c4113dSnw141292#pragma ident "%Z%%M% %I% %E% SMI" 3*c5c4113dSnw141292 4*c5c4113dSnw141292# 2001 September 15 5*c5c4113dSnw141292# 6*c5c4113dSnw141292# The author disclaims copyright to this source code. In place of 7*c5c4113dSnw141292# a legal notice, here is a blessing: 8*c5c4113dSnw141292# 9*c5c4113dSnw141292# May you do good and not evil. 10*c5c4113dSnw141292# May you find forgiveness for yourself and forgive others. 11*c5c4113dSnw141292# May you share freely, never taking more than you give. 12*c5c4113dSnw141292# 13*c5c4113dSnw141292#*********************************************************************** 14*c5c4113dSnw141292# This file implements regression tests for SQLite library. The 15*c5c4113dSnw141292# focus of this file is testing SELECT statements that are part of 16*c5c4113dSnw141292# expressions. 17*c5c4113dSnw141292# 18*c5c4113dSnw141292# $Id: subselect.test,v 1.7 2002/07/15 18:55:26 drh Exp $ 19*c5c4113dSnw141292 20*c5c4113dSnw141292set testdir [file dirname $argv0] 21*c5c4113dSnw141292source $testdir/tester.tcl 22*c5c4113dSnw141292 23*c5c4113dSnw141292# Basic sanity checking. Try a simple subselect. 24*c5c4113dSnw141292# 25*c5c4113dSnw141292do_test subselect-1.1 { 26*c5c4113dSnw141292 execsql { 27*c5c4113dSnw141292 CREATE TABLE t1(a int, b int); 28*c5c4113dSnw141292 INSERT INTO t1 VALUES(1,2); 29*c5c4113dSnw141292 INSERT INTO t1 VALUES(3,4); 30*c5c4113dSnw141292 INSERT INTO t1 VALUES(5,6); 31*c5c4113dSnw141292 } 32*c5c4113dSnw141292 execsql {SELECT * FROM t1 WHERE a = (SELECT count(*) FROM t1)} 33*c5c4113dSnw141292} {3 4} 34*c5c4113dSnw141292 35*c5c4113dSnw141292# Try a select with more than one result column. 36*c5c4113dSnw141292# 37*c5c4113dSnw141292do_test subselect-1.2 { 38*c5c4113dSnw141292 set v [catch {execsql {SELECT * FROM t1 WHERE a = (SELECT * FROM t1)}} msg] 39*c5c4113dSnw141292 lappend v $msg 40*c5c4113dSnw141292} {1 {only a single result allowed for a SELECT that is part of an expression}} 41*c5c4113dSnw141292 42*c5c4113dSnw141292# A subselect without an aggregate. 43*c5c4113dSnw141292# 44*c5c4113dSnw141292do_test subselect-1.3a { 45*c5c4113dSnw141292 execsql {SELECT b from t1 where a = (SELECT a FROM t1 WHERE b=2)} 46*c5c4113dSnw141292} {2} 47*c5c4113dSnw141292do_test subselect-1.3b { 48*c5c4113dSnw141292 execsql {SELECT b from t1 where a = (SELECT a FROM t1 WHERE b=4)} 49*c5c4113dSnw141292} {4} 50*c5c4113dSnw141292do_test subselect-1.3c { 51*c5c4113dSnw141292 execsql {SELECT b from t1 where a = (SELECT a FROM t1 WHERE b=6)} 52*c5c4113dSnw141292} {6} 53*c5c4113dSnw141292do_test subselect-1.3c { 54*c5c4113dSnw141292 execsql {SELECT b from t1 where a = (SELECT a FROM t1 WHERE b=8)} 55*c5c4113dSnw141292} {} 56*c5c4113dSnw141292 57*c5c4113dSnw141292# What if the subselect doesn't return any value. We should get 58*c5c4113dSnw141292# NULL as the result. Check it out. 59*c5c4113dSnw141292# 60*c5c4113dSnw141292do_test subselect-1.4 { 61*c5c4113dSnw141292 execsql {SELECT b from t1 where a = coalesce((SELECT a FROM t1 WHERE b=5),1)} 62*c5c4113dSnw141292} {2} 63*c5c4113dSnw141292 64*c5c4113dSnw141292# Try multiple subselects within a single expression. 65*c5c4113dSnw141292# 66*c5c4113dSnw141292do_test subselect-1.5 { 67*c5c4113dSnw141292 execsql { 68*c5c4113dSnw141292 CREATE TABLE t2(x int, y int); 69*c5c4113dSnw141292 INSERT INTO t2 VALUES(1,2); 70*c5c4113dSnw141292 INSERT INTO t2 VALUES(2,4); 71*c5c4113dSnw141292 INSERT INTO t2 VALUES(3,8); 72*c5c4113dSnw141292 INSERT INTO t2 VALUES(4,16); 73*c5c4113dSnw141292 } 74*c5c4113dSnw141292 execsql { 75*c5c4113dSnw141292 SELECT y from t2 76*c5c4113dSnw141292 WHERE x = (SELECT sum(b) FROM t1 where a notnull) - (SELECT sum(a) FROM t1) 77*c5c4113dSnw141292 } 78*c5c4113dSnw141292} {8} 79*c5c4113dSnw141292 80*c5c4113dSnw141292# Try something useful. Delete every entry from t2 where the 81*c5c4113dSnw141292# x value is less than half of the maximum. 82*c5c4113dSnw141292# 83*c5c4113dSnw141292do_test subselect-1.6 { 84*c5c4113dSnw141292 execsql {DELETE FROM t2 WHERE x < 0.5*(SELECT max(x) FROM t2)} 85*c5c4113dSnw141292 execsql {SELECT x FROM t2 ORDER BY x} 86*c5c4113dSnw141292} {2 3 4} 87*c5c4113dSnw141292 88*c5c4113dSnw141292# Make sure sorting works for SELECTs there used as a scalar expression. 89*c5c4113dSnw141292# 90*c5c4113dSnw141292do_test subselect-2.1 { 91*c5c4113dSnw141292 execsql { 92*c5c4113dSnw141292 SELECT (SELECT a FROM t1 ORDER BY a), (SELECT a FROM t1 ORDER BY a DESC) 93*c5c4113dSnw141292 } 94*c5c4113dSnw141292} {1 5} 95*c5c4113dSnw141292do_test subselect-2.2 { 96*c5c4113dSnw141292 execsql { 97*c5c4113dSnw141292 SELECT 1 IN (SELECT a FROM t1 ORDER BY a); 98*c5c4113dSnw141292 } 99*c5c4113dSnw141292} {1} 100*c5c4113dSnw141292do_test subselect-2.3 { 101*c5c4113dSnw141292 execsql { 102*c5c4113dSnw141292 SELECT 2 IN (SELECT a FROM t1 ORDER BY a DESC); 103*c5c4113dSnw141292 } 104*c5c4113dSnw141292} {0} 105*c5c4113dSnw141292 106*c5c4113dSnw141292# Verify that the ORDER BY clause is honored in a subquery. 107*c5c4113dSnw141292# 108*c5c4113dSnw141292do_test subselect-3.1 { 109*c5c4113dSnw141292 execsql { 110*c5c4113dSnw141292 CREATE TABLE t3(x int); 111*c5c4113dSnw141292 INSERT INTO t3 SELECT a FROM t1 UNION ALL SELECT b FROM t1; 112*c5c4113dSnw141292 SELECT * FROM t3 ORDER BY x; 113*c5c4113dSnw141292 } 114*c5c4113dSnw141292} {1 2 3 4 5 6} 115*c5c4113dSnw141292do_test subselect-3.2 { 116*c5c4113dSnw141292 execsql { 117*c5c4113dSnw141292 SELECT sum(x) FROM (SELECT x FROM t3 ORDER BY x LIMIT 2); 118*c5c4113dSnw141292 } 119*c5c4113dSnw141292} {3} 120*c5c4113dSnw141292do_test subselect-3.3 { 121*c5c4113dSnw141292 execsql { 122*c5c4113dSnw141292 SELECT sum(x) FROM (SELECT x FROM t3 ORDER BY x DESC LIMIT 2); 123*c5c4113dSnw141292 } 124*c5c4113dSnw141292} {11} 125*c5c4113dSnw141292do_test subselect-3.4 { 126*c5c4113dSnw141292 execsql { 127*c5c4113dSnw141292 SELECT (SELECT x FROM t3 ORDER BY x); 128*c5c4113dSnw141292 } 129*c5c4113dSnw141292} {1} 130*c5c4113dSnw141292do_test subselect-3.5 { 131*c5c4113dSnw141292 execsql { 132*c5c4113dSnw141292 SELECT (SELECT x FROM t3 ORDER BY x DESC); 133*c5c4113dSnw141292 } 134*c5c4113dSnw141292} {6} 135*c5c4113dSnw141292do_test subselect-3.6 { 136*c5c4113dSnw141292 execsql { 137*c5c4113dSnw141292 SELECT (SELECT x FROM t3 ORDER BY x LIMIT 1); 138*c5c4113dSnw141292 } 139*c5c4113dSnw141292} {1} 140*c5c4113dSnw141292do_test subselect-3.7 { 141*c5c4113dSnw141292 execsql { 142*c5c4113dSnw141292 SELECT (SELECT x FROM t3 ORDER BY x DESC LIMIT 1); 143*c5c4113dSnw141292 } 144*c5c4113dSnw141292} {6} 145*c5c4113dSnw141292do_test subselect-3.8 { 146*c5c4113dSnw141292 execsql { 147*c5c4113dSnw141292 SELECT (SELECT x FROM t3 ORDER BY x LIMIT 1 OFFSET 2); 148*c5c4113dSnw141292 } 149*c5c4113dSnw141292} {3} 150*c5c4113dSnw141292do_test subselect-3.9 { 151*c5c4113dSnw141292 execsql { 152*c5c4113dSnw141292 SELECT (SELECT x FROM t3 ORDER BY x DESC LIMIT 1 OFFSET 2); 153*c5c4113dSnw141292 } 154*c5c4113dSnw141292} {4} 155*c5c4113dSnw141292 156*c5c4113dSnw141292 157*c5c4113dSnw141292 158*c5c4113dSnw141292finish_test 159