3 # The author disclaims copyright to this source code. In place of
4 # a legal notice, here is a blessing:
6 # May you do good and not evil.
7 # May you find forgiveness for yourself and forgive others.
8 # May you share freely, never taking more than you give.
10 #***********************************************************************
11 # This file implements regression tests for SQLite library.
13 # The focus of this file is testing how SQLite generates the names
14 # of columns in a result set.
17 set testdir [file dirname $argv0]
18 source $testdir/tester.tcl
20 # Rules (applied in order):
22 # (1) If there is an AS clause, use it.
24 # (2) A non-trival expression (not a table column name) then the name is
25 # a copy of the expression text.
27 # (3) If short_column_names=ON, then just the abbreviated column name without
30 # (4) When short_column_names=OFF and full_column_names=OFF then
31 # use case (2) for simple queries and case (5) for joins.
33 # (5) When short_column_names=OFF and full_column_names=ON then
34 # use the form: TABLE.COLUMN
38 # Verify the default settings for short_column_name and full_column_name
41 db eval {PRAGMA short_column_names}
44 db eval {PRAGMA full_column_names}
47 # Tests for then short=ON and full=any
51 CREATE TABLE tabc(a,b,c);
52 INSERT INTO tabc VALUES(1,2,3);
53 CREATE TABLE txyz(x,y,z);
54 INSERT INTO txyz VALUES(4,5,6);
55 CREATE TABLE tboth(a,b,c,x,y,z);
56 INSERT INTO tboth VALUES(11,12,13,14,15,16);
57 CREATE VIEW v1 AS SELECT tabC.a, txyZ.x, *
58 FROM tabc, txyz ORDER BY 1 LIMIT 1;
59 CREATE VIEW v2 AS SELECT tabC.a, txyZ.x, tboTh.a, tbotH.x, *
60 FROM tabc, txyz, tboth ORDER BY 1 LIMIT 1;
68 SELECT Tabc.a, tAbc.b, taBc.c, * FROM tabc
70 } {a 1 b 2 c 3 a 1 b 2 c 3}
73 SELECT +tabc.a, -tabc.b, tabc.c, * FROM tabc
75 } {+tabc.a 1 -tabc.b -2 c 3 a 1 b 2 c 3}
78 SELECT +tabc.a AS AAA, -tabc.b AS BBB, tabc.c CCC, * FROM tabc
80 } {AAA 1 BBB -2 CCC 3 a 1 b 2 c 3}
83 SELECT tabc.a, txyz.x, * FROM tabc, txyz;
85 } {a 1 x 4 a 1 b 2 c 3 x 4 y 5 z 6}
88 SELECT tabc.a, txyz.x, tabc.*, txyz.* FROM tabc, txyz;
90 } {a 1 x 4 a 1 b 2 c 3 x 4 y 5 z 6}
93 SELECT tabc.a, txyz.x, tboth.a, tboth.x, * FROM tabc, txyz, tboth;
95 } {a 11 x 14 a 11 x 14 a 11 b 12 c 13 x 14 y 15 z 16 a 11 b 12 c 13 x 14 y 15 z 16}
98 SELECT * FROM v1 ORDER BY 2;
100 } {a 1 x 4 a:1 1 b 2 c 3 x:1 4 y 5 z 6}
101 do_test colname-2.9 {
103 SELECT * FROM v2 ORDER BY 2;
105 } {a 1 x 4 a:1 11 x:1 14 a:2 1 b 2 c 3 x:2 4 y 5 z 6 a:3 11 b:1 12 c:1 13 x:3 14 y:1 15 z:1 16}
108 # Tests for short=OFF and full=OFF
110 do_test colname-3.1 {
112 PRAGMA short_column_names=OFF;
113 PRAGMA full_column_names=OFF;
114 CREATE VIEW v3 AS SELECT tabC.a, txyZ.x, *
115 FROM tabc, txyz ORDER BY 1 LIMIT 1;
116 CREATE VIEW v4 AS SELECT tabC.a, txyZ.x, tboTh.a, tbotH.x, *
117 FROM tabc, txyz, tboth ORDER BY 1 LIMIT 1;
123 do_test colname-3.2 {
125 SELECT Tabc.a, tAbc.b, taBc.c FROM tabc
127 } {Tabc.a 1 tAbc.b 2 taBc.c 3}
128 do_test colname-3.3 {
130 SELECT +tabc.a, -tabc.b, tabc.c FROM tabc
132 } {+tabc.a 1 -tabc.b -2 tabc.c 3}
133 do_test colname-3.4 {
135 SELECT +tabc.a AS AAA, -tabc.b AS BBB, tabc.c CCC FROM tabc
137 } {AAA 1 BBB -2 CCC 3}
138 do_test colname-3.5 {
140 SELECT Tabc.a, Txyz.x, * FROM tabc, txyz;
142 } {Tabc.a 1 Txyz.x 4 a 1 b 2 c 3 x 4 y 5 z 6}
143 do_test colname-3.6 {
145 SELECT tabc.*, txyz.* FROM tabc, txyz;
147 } {a 1 b 2 c 3 x 4 y 5 z 6}
148 do_test colname-3.7 {
150 SELECT * FROM tabc, txyz, tboth;
152 } {a 11 b 12 c 13 x 14 y 15 z 16 a 11 b 12 c 13 x 14 y 15 z 16}
153 do_test colname-3.8 {
155 SELECT v1.a, * FROM v1 ORDER BY 2;
157 } {v1.a 1 a 1 x 4 a:1 1 b 2 c 3 x:1 4 y 5 z 6}
158 do_test colname-3.9 {
160 SELECT * FROM v2 ORDER BY 2;
162 } {a 1 x 4 a:1 11 x:1 14 a:2 1 b 2 c 3 x:2 4 y 5 z 6 a:3 11 b:1 12 c:1 13 x:3 14 y:1 15 z:1 16}
163 do_test colname-3.10 {
165 SELECT * FROM v3 ORDER BY 2;
167 } {a 1 x 4 a:1 1 b 2 c 3 x:1 4 y 5 z 6}
168 do_test colname-3.11 {
170 SELECT * FROM v4 ORDER BY 2;
172 } {a 1 x 4 a:1 11 x:1 14 a:2 1 b 2 c 3 x:2 4 y 5 z 6 a:3 11 b:1 12 c:1 13 x:3 14 y:1 15 z:1 16}
174 # Test for short=OFF and full=ON
176 do_test colname-4.1 {
178 PRAGMA short_column_names=OFF;
179 PRAGMA full_column_names=ON;
180 CREATE VIEW v5 AS SELECT tabC.a, txyZ.x, *
181 FROM tabc, txyz ORDER BY 1 LIMIT 1;
182 CREATE VIEW v6 AS SELECT tabC.a, txyZ.x, tboTh.a, tbotH.x, *
183 FROM tabc, txyz, tboth ORDER BY 1 LIMIT 1;
188 } {tabc.a 1 tabc.b 2 tabc.c 3}
189 do_test colname-4.2 {
191 SELECT Tabc.a, tAbc.b, taBc.c FROM tabc
193 } {tabc.a 1 tabc.b 2 tabc.c 3}
194 do_test colname-4.3 {
196 SELECT +tabc.a, -tabc.b, tabc.c FROM tabc
198 } {+tabc.a 1 -tabc.b -2 tabc.c 3}
199 do_test colname-4.4 {
201 SELECT +tabc.a AS AAA, -tabc.b AS BBB, tabc.c CCC FROM tabc
203 } {AAA 1 BBB -2 CCC 3}
204 do_test colname-4.5 {
206 SELECT Tabc.a, Txyz.x, * FROM tabc, txyz;
208 } {tabc.a 1 txyz.x 4 tabc.a 1 tabc.b 2 tabc.c 3 txyz.x 4 txyz.y 5 txyz.z 6}
209 do_test colname-4.6 {
211 SELECT tabc.*, txyz.* FROM tabc, txyz;
213 } {tabc.a 1 tabc.b 2 tabc.c 3 txyz.x 4 txyz.y 5 txyz.z 6}
214 do_test colname-4.7 {
216 SELECT * FROM tabc, txyz, tboth;
218 } {tabc.a 1 tabc.b 2 tabc.c 3 txyz.x 4 txyz.y 5 txyz.z 6 tboth.a 11 tboth.b 12 tboth.c 13 tboth.x 14 tboth.y 15 tboth.z 16}
219 do_test colname-4.8 {
221 SELECT * FROM v1 ORDER BY 2;
223 } {v1.a 1 v1.x 4 v1.a:1 1 v1.b 2 v1.c 3 v1.x:1 4 v1.y 5 v1.z 6}
224 do_test colname-4.9 {
226 SELECT * FROM v2 ORDER BY 2;
228 } {v2.a 1 v2.x 4 v2.a:1 11 v2.x:1 14 v2.a:2 1 v2.b 2 v2.c 3 v2.x:2 4 v2.y 5 v2.z 6 v2.a:3 11 v2.b:1 12 v2.c:1 13 v2.x:3 14 v2.y:1 15 v2.z:1 16}
229 do_test colname-4.10 {
231 SELECT * FROM v3 ORDER BY 2;
233 } {v3.a 1 v3.x 4 v3.a:1 1 v3.b 2 v3.c 3 v3.x:1 4 v3.y 5 v3.z 6}
234 do_test colname-4.11 {
236 SELECT * FROM v4 ORDER BY 2;
238 } {v4.a 1 v4.x 4 v4.a:1 11 v4.x:1 14 v4.a:2 1 v4.b 2 v4.c 3 v4.x:2 4 v4.y 5 v4.z 6 v4.a:3 11 v4.b:1 12 v4.c:1 13 v4.x:3 14 v4.y:1 15 v4.z:1 16}
239 do_test colname-4.12 {
241 SELECT * FROM v5 ORDER BY 2;
243 } {v5.a 1 v5.x 4 v5.a:1 1 v5.b 2 v5.c 3 v5.x:1 4 v5.y 5 v5.z 6}
244 do_test colname-4.13 {
246 SELECT * FROM v6 ORDER BY 2;
248 } {v6.a 1 v6.x 4 v6.a:1 11 v6.x:1 14 v6.a:2 1 v6.b 2 v6.c 3 v6.x:2 4 v6.y 5 v6.z 6 v6.a:3 11 v6.b:1 12 v6.c:1 13 v6.x:3 14 v6.y:1 15 v6.z:1 16}
251 do_test colname-5.1 {
253 SELECT x.* FROM sqlite_master X LIMIT 1;
255 } {table tabc tabc x {CREATE TABLE tabc(a,b,c)}}
257 # ticket #3370, #3371, #3372
259 do_test colname-6.1 {
263 CREATE TABLE t6(a, ['a'], ["a"], "[a]", [`a`]);
264 INSERT INTO t6 VALUES(1,2,3,4,5);
266 execsql2 {SELECT * FROM t6}
267 } {a 1 'a' 2 {"a"} 3 {[a]} 4 `a` 5}
268 do_test colname-6.2 {
269 execsql2 {SELECT ['a'], [`a`], "[a]", [a], ["a"] FROM t6}
270 } {'a' 2 `a` 5 {[a]} 4 a 1 {"a"} 3}
271 do_test colname-6.3 {
272 execsql2 {SELECT "'a'", "`a`", "[a]", "a", """a""" FROM t6}
273 } {'a' 2 `a` 5 {[a]} 4 a 1 {"a"} 3}
274 do_test colname-6.4 {
275 execsql2 {SELECT `'a'`, ```a```, `[a]`, `a`, `"a"` FROM t6}
276 } {'a' 2 `a` 5 {[a]} 4 a 1 {"a"} 3}
277 do_test colname-6.11 {
278 execsql2 {SELECT a, max(a) AS m FROM t6}
280 do_test colname-6.12 {
281 execsql2 {SELECT `a`, max(a) AS m FROM t6}
283 do_test colname-6.13 {
284 execsql2 {SELECT "a", max(a) AS m FROM t6}
286 do_test colname-6.14 {
287 execsql2 {SELECT [a], max(a) AS m FROM t6}
289 do_test colname-6.15 {
290 execsql2 {SELECT t6.a, max(a) AS m FROM t6}
292 do_test colname-6.16 {
293 execsql2 {SELECT ['a'], max(['a']) AS m FROM t6}
295 do_test colname-6.17 {
296 execsql2 {SELECT ["a"], max(["a"]) AS m FROM t6}
298 do_test colname-6.18 {
299 execsql2 {SELECT "[a]", max("[a]") AS m FROM t6}
301 do_test colname-6.19 {
302 execsql2 {SELECT "`a`", max([`a`]) AS m FROM t6}
307 # We cannot find anything wrong, but it never hurts to add another
310 do_test colname-7.1 {
312 CREATE TABLE t7(x INTEGER PRIMARY KEY, y);
313 INSERT INTO t7 VALUES(1,2);
315 execsql2 {SELECT rowid, * FROM t7}
318 # Tickets #3893 and #3984. (Same problem; independently reported)
320 do_test colname-8.1 {
322 CREATE TABLE "t3893"("x");
323 INSERT INTO t3893 VALUES(123);
324 SELECT "y"."x" FROM (SELECT "x" FROM "t3893") AS "y";
328 # 2017-07-29: Interaction between column naming and query flattening.
329 # For years now, the query flattener has inserted AS clauses on the
330 # outer query that were the original SQL text of the column. This caused
331 # column-name shifts when the query flattener was enhanced, breaking
332 # legacy applications. See https://sqlite.org/src/info/41c27bc0ff1d3135
335 # To fix this, the column naming logic was moved ahead of the query
336 # flattener so that column names are assigned before the query flattener
341 do_test colname-9.100 {
343 CREATE TABLE t1(a,b);
344 INSERT INTO t1 VALUES(1,2);
345 CREATE VIEW v1(x,y) AS SELECT a,b FROM t1;
347 execsql2 {SELECT v1.x, (Y) FROM v1}
348 # Prior to the fix, this would return: "v1.x 1 (Y) 2"
350 do_test colname-9.110 {
351 execsql2 {SELECT * FROM v1}
353 do_test colname-9.120 {
355 CREATE VIEW v2(x,y) AS SELECT a,b FROM t1 LIMIT 10;
357 execsql2 {SELECT * FROM v2 WHERE 1}
359 do_test colname-9.130 {
360 execsql2 {SELECT v2.x, [v2].[y] FROM v2 WHERE 1}
362 do_test colname-9.140 {
363 execsql2 {SELECT +x, +y FROM v2 WHERE 1}
366 do_test colname-9.200 {
368 CREATE TABLE t2(c,d);
369 INSERT INTO t2 VALUES(3,4);
370 CREATE VIEW v3 AS SELECT c AS a, d AS b FROM t2;
372 execsql2 {SELECT t1.a, v3.a AS n FROM t1 LEFT JOIN v3}
374 do_test colname-9.211 {
375 execsql2 {SELECT t1.a AS n, v3.a FROM t1 JOIN v3}
377 do_test colname-9.210 {
378 execsql2 {SELECT t1.a, v3.a AS n FROM t1 JOIN v3}
381 # 2017-12-23: Ticket https://www.sqlite.org/src/info/3b4450072511e621
382 # Inconsistent column names in CREATE TABLE AS
384 # Verify that the names of columns in the created table of a CREATE TABLE AS
385 # are the same as the names of result columns in the SELECT statement.
387 do_execsql_test colname-9.300 {
388 DROP TABLE IF EXISTS t1;
389 DROP TABLE IF EXISTS t2;
390 CREATE TABLE t1(aaa INT);
391 INSERT INTO t1(aaa) VALUES(123);
393 do_test colname-9.310 {
394 execsql2 {SELECT BBb FROM (SELECT aaa AS Bbb FROM t1)}
397 do_execsql_test colname-9.320 {
398 CREATE TABLE t2 AS SELECT BBb FROM (SELECT aaa AS Bbb FROM t1);
399 SELECT name FROM pragma_table_info('t2');
402 do_execsql_test colname-9.330 { -- added 2019-08-10 to invalidate
403 DROP TABLE IF EXISTS t1; -- a couple assert()s that were
404 CREATE TABLE t1(a); -- added by ticket 3b44500725
405 INSERT INTO t1 VALUES(17),(2),(99),(-3),(7);
406 SELECT (SELECT avg(a) UNION SELECT min(a) OVER()) FROM t1;
409 # Issue detected by OSSFuzz on 2017-12-24 (Christmas Eve)
410 # caused by check-in https://sqlite.org/src/info/6b2ff26c25
412 # Prior to being fixed, the following CREATE TABLE was dereferencing
413 # a NULL pointer and segfaulting.
415 do_catchsql_test colname-9.400 {
416 CREATE TABLE t4 AS SELECT #0;
417 } {1 {near "#0": syntax error}}
419 # Issue detected by OSSFuzz on 2017-12-25 (Christmas Day)
420 # also caused by check-in https://sqlite.org/src/info/6b2ff26c25
422 # Prior to being fixed, the following CREATE TABLE caused an
425 do_catchsql_test colname-9.410 {
426 CREATE TABLE t5 AS SELECT RAISE(abort,a);
427 } {1 {RAISE() may only be used within a trigger-program}}
429 # Make sure the quotation marks get removed from the column names
430 # when constructing a new table from an aggregate SELECT.
431 # Email from Juergen Palm on 2017-07-11.
433 do_execsql_test colname-10.100 {
434 DROP TABLE IF EXISTS t1;
435 CREATE TABLE t1("with space" TEXT);
436 DROP TABLE IF EXISTS t2;
437 CREATE TABLE t2 AS SELECT "with space" FROM t1;
438 PRAGMA table_info(t2);
439 } {0 {with space} TEXT 0 {} 0}
440 do_execsql_test colname-10.110 {
441 DROP TABLE IF EXISTS t3;
442 CREATE TABLE t3 AS SELECT "with space" FROM t1 GROUP BY 1;
443 PRAGMA table_info(t3);
444 } {0 {with space} TEXT 0 {} 0}