sqlite/test/select7.test
drh 1193e4679d Do not let the number of terms on a VALUES clause be limited by
SQLITE_LIMIT_COMPOUND_SELECT, even if the VALUES clause contains elements
that appear to be variables due to the use of double-quoted string literals.
[https://issues.chromium.org/issues/358174302|Chromium issue 358174302].

FossilOrigin-Name: 670beb133eb203065a75022f0c6db7c605a4e0e22c8ef6d6b4724be2663ff3dc
2024-08-08 14:45:50 +00:00

251 lines
7.3 KiB
Plaintext

# The author disclaims copyright to this source code. In place of
# a legal notice, here is a blessing:
#
# May you do good and not evil.
# May you find forgiveness for yourself and forgive others.
# May you share freely, never taking more than you give.
#
#***********************************************************************
# This file implements regression tests for SQLite library. The
# focus of this file is testing compute SELECT statements and nested
# views.
#
# $Id: select7.test,v 1.11 2007/09/12 17:01:45 danielk1977 Exp $
set testdir [file dirname $argv0]
source $testdir/tester.tcl
set testprefix select7
ifcapable compound {
# A 3-way INTERSECT. Ticket #875
ifcapable tempdb {
do_test select7-1.1 {
execsql {
create temp table t1(x);
insert into t1 values('amx');
insert into t1 values('anx');
insert into t1 values('amy');
insert into t1 values('bmy');
select * from t1 where x like 'a__'
intersect select * from t1 where x like '_m_'
intersect select * from t1 where x like '__x';
}
} {amx}
}
# Nested views do not handle * properly. Ticket #826.
#
ifcapable view {
do_test select7-2.1 {
execsql {
CREATE TABLE x(id integer primary key, a TEXT NULL);
INSERT INTO x (a) VALUES ('first');
CREATE TABLE tempx(id integer primary key, a TEXT NULL);
INSERT INTO tempx (a) VALUES ('t-first');
CREATE VIEW tv1 AS SELECT x.id, tx.id FROM x JOIN tempx tx ON tx.id=x.id;
CREATE VIEW tv1b AS SELECT x.id, tx.id FROM x JOIN tempx tx on tx.id=x.id;
CREATE VIEW tv2 AS SELECT * FROM tv1 UNION SELECT * FROM tv1b;
SELECT * FROM tv2;
}
} {1 1}
} ;# ifcapable view
} ;# ifcapable compound
# Do not allow GROUP BY without an aggregate. Ticket #1039.
#
# Change: force any query with a GROUP BY clause to be processed as
# an aggregate query, whether it contains aggregates or not.
#
ifcapable subquery {
# do_test select7-3.1 {
# catchsql {
# SELECT * FROM (SELECT * FROM sqlite_master) GROUP BY name
# }
# } {1 {GROUP BY may only be used on aggregate queries}}
do_test select7-3.1 {
catchsql {
SELECT * FROM (SELECT * FROM sqlite_master) GROUP BY name
}
} [list 0 [execsql {SELECT * FROM sqlite_master ORDER BY name}]]
}
# Ticket #2018 - Make sure names are resolved correctly on all
# SELECT statements of a compound subquery.
#
ifcapable {subquery && compound} {
do_test select7-4.1 {
execsql {
CREATE TABLE IF NOT EXISTS photo(pk integer primary key, x);
CREATE TABLE IF NOT EXISTS tag(pk integer primary key, fk int, name);
SELECT P.pk from PHOTO P WHERE NOT EXISTS (
SELECT T2.pk from TAG T2 WHERE T2.fk = P.pk
EXCEPT
SELECT T3.pk from TAG T3 WHERE T3.fk = P.pk AND T3.name LIKE '%foo%'
);
}
} {}
do_test select7-4.2 {
execsql {
INSERT INTO photo VALUES(1,1);
INSERT INTO photo VALUES(2,2);
INSERT INTO photo VALUES(3,3);
INSERT INTO tag VALUES(11,1,'one');
INSERT INTO tag VALUES(12,1,'two');
INSERT INTO tag VALUES(21,1,'one-b');
SELECT P.pk from PHOTO P WHERE NOT EXISTS (
SELECT T2.pk from TAG T2 WHERE T2.fk = P.pk
EXCEPT
SELECT T3.pk from TAG T3 WHERE T3.fk = P.pk AND T3.name LIKE '%foo%'
);
}
} {2 3}
}
# ticket #2347
#
ifcapable {subquery && compound} {
do_test select7-5.1 {
catchsql {
CREATE TABLE t2(a,b);
SELECT 5 IN (SELECT a,b FROM t2);
}
} {1 {sub-select returns 2 columns - expected 1}}
do_test select7-5.2 {
catchsql {
SELECT 5 IN (SELECT * FROM t2);
}
} {1 {sub-select returns 2 columns - expected 1}}
do_test select7-5.3 {
catchsql {
SELECT 5 IN (SELECT a,b FROM t2 UNION SELECT b,a FROM t2);
}
} {1 {sub-select returns 2 columns - expected 1}}
do_test select7-5.4 {
catchsql {
SELECT 5 IN (SELECT * FROM t2 UNION SELECT * FROM t2);
}
} {1 {sub-select returns 2 columns - expected 1}}
}
# Verify that an error occurs if you have too many terms on a
# compound select statement.
#
if {[clang_sanitize_address]==0} {
ifcapable compound {
if {$SQLITE_MAX_COMPOUND_SELECT>0} {
set sql {SELECT 0}
set result 0
for {set i 1} {$i<$SQLITE_MAX_COMPOUND_SELECT} {incr i} {
append sql " UNION ALL SELECT $i"
lappend result $i
}
do_test select7-6.1 {
catchsql $sql
} [list 0 $result]
append sql { UNION ALL SELECT 99999999}
do_test select7-6.2 {
catchsql $sql
} {1 {too many terms in compound SELECT}}
}
}
}
# https://issues.chromium.org/issues/358174302
# Need to support an unlimited number of terms in a VALUES clause, even
# if some of those terms contain double-quoted string literals.
#
do_execsql_test select7-6.5 {
DROP TABLE IF EXISTS t1;
CREATE TABLE t1(a,b,c);
}
sqlite3_limit db SQLITE_LIMIT_COMPOUND_SELECT 10
sqlite3_db_config db SQLITE_DBCONFIG_DQS_DML 0
do_catchsql_test select7-6.6 {
INSERT INTO t1 VALUES
(NULL,0,""), (X'',0.0,0.0), (X'',X'',""), (0.0,0.0,""), (NULL,NULL,0.0),
(0,"",0), (0.0,X'',0), ("",X'',0.0), (0.0,X'',NULL), (0,NULL,""),
(0,"",NULL), (0.0,NULL,X''), ("",X'',NULL), (NULL,0,""),
(0,NULL,0), (X'',X'',0.0);
} {1 {no such column: "" - should this be a string literal in single-quotes?}}
do_execsql_test select7-6.7 {
SELECT count(*) FROM t1;
} {0}
sqlite3_db_config db SQLITE_DBCONFIG_DQS_DML 1
do_catchsql_test select7-6.8 {
INSERT INTO t1 VALUES
(NULL,0,""), (X'',0.0,0.0), (X'',X'',""), (0.0,0.0,""), (NULL,NULL,0.0),
(0,"",0), (0.0,X'',0), ("",X'',0.0), (0.0,X'',NULL), (0,NULL,""),
(0,"",NULL), (0.0,NULL,X''), ("",X'',NULL), (NULL,0,""),
(0,NULL,0), (X'',X'',0.0);
} {0 {}}
do_execsql_test select7-6.9 {
SELECT count(*) FROM t1;
} {16}
# This block of tests verifies that bug aa92c76cd4 is fixed.
#
do_test select7-7.1 {
execsql {
CREATE TABLE t3(a REAL);
INSERT INTO t3 VALUES(44.0);
INSERT INTO t3 VALUES(56.0);
}
} {}
do_test select7-7.2 {
execsql {
pragma vdbe_trace = 0;
SELECT (CASE WHEN a=0 THEN 0 ELSE (a + 25) / 50 END) AS categ, count(*)
FROM t3 GROUP BY categ
}
} {1.38 1 1.62 1}
do_test select7-7.3 {
execsql {
CREATE TABLE t4(a REAL);
INSERT INTO t4 VALUES( 2.0 );
INSERT INTO t4 VALUES( 3.0 );
}
} {}
do_test select7-7.4 {
execsql {
SELECT (CASE WHEN a=0 THEN 'zero' ELSE a/2 END) AS t FROM t4 GROUP BY t;
}
} {1.0 1.5}
do_test select7-7.5 {
execsql { SELECT a=0, typeof(a) FROM t4 }
} {0 real 0 real}
do_test select7-7.6 {
execsql { SELECT a=0, typeof(a) FROM t4 GROUP BY a }
} {0 real 0 real}
do_test select7-7.7 {
execsql {
CREATE TABLE t5(a TEXT, b INT);
INSERT INTO t5 VALUES(123, 456);
SELECT typeof(a), a FROM t5 GROUP BY a HAVING a<b;
}
} {text 123}
do_execsql_test 8.0 {
CREATE TABLE t01(x, y);
CREATE TABLE t02(x, y);
}
do_catchsql_test 8.1 {
SELECT * FROM (
SELECT * FROM t01 UNION SELECT x FROM t02
) WHERE y=1
} {1 {SELECTs to the left and right of UNION do not have the same number of result columns}}
do_catchsql_test 8.2 {
CREATE VIEW v0 as SELECT x, y FROM t01 UNION SELECT x FROM t02;
EXPLAIN QUERY PLAN SELECT * FROM v0 WHERE x='0' OR y;
} {1 {SELECTs to the left and right of UNION do not have the same number of result columns}}
finish_test