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.
16 # $Id: colname.test,v 1.7 2009/06/02 15:47:38 drh Exp $
18 set testdir [file dirname $argv0]
19 source $testdir/tester.tcl
21 # Rules (applied in order):
23 # (1) If there is an AS clause, use it.
25 # (2) A non-trival expression (not a table column name) then the name is
26 # a copy of the expression text.
28 # (3) If short_column_names=ON, then just the abbreviated column name without
31 # (4) When short_column_names=OFF and full_column_names=OFF then
32 # use case (2) for simple queries and case (5) for joins.
34 # (5) When short_column_names=OFF and full_column_names=ON then
35 # use the form: TABLE.COLUMN
39 # Verify the default settings for short_column_name and full_column_name
42 db eval {PRAGMA short_column_names}
45 db eval {PRAGMA full_column_names}
48 # Tests for then short=ON and full=any
52 CREATE TABLE tabc(a,b,c);
53 INSERT INTO tabc VALUES(1,2,3);
54 CREATE TABLE txyz(x,y,z);
55 INSERT INTO txyz VALUES(4,5,6);
56 CREATE TABLE tboth(a,b,c,x,y,z);
57 INSERT INTO tboth VALUES(11,12,13,14,15,16);
58 CREATE VIEW v1 AS SELECT tabC.a, txyZ.x, *
59 FROM tabc, txyz ORDER BY 1 LIMIT 1;
60 CREATE VIEW v2 AS SELECT tabC.a, txyZ.x, tboTh.a, tbotH.x, *
61 FROM tabc, txyz, tboth ORDER BY 1 LIMIT 1;
69 SELECT Tabc.a, tAbc.b, taBc.c, * FROM tabc
71 } {a 1 b 2 c 3 a 1 b 2 c 3}
74 SELECT +tabc.a, -tabc.b, tabc.c, * FROM tabc
76 } {+tabc.a 1 -tabc.b -2 c 3 a 1 b 2 c 3}
79 SELECT +tabc.a AS AAA, -tabc.b AS BBB, tabc.c CCC, * FROM tabc
81 } {AAA 1 BBB -2 CCC 3 a 1 b 2 c 3}
84 SELECT tabc.a, txyz.x, * FROM tabc, txyz;
86 } {a 1 x 4 a 1 b 2 c 3 x 4 y 5 z 6}
89 SELECT tabc.a, txyz.x, tabc.*, txyz.* FROM tabc, txyz;
91 } {a 1 x 4 a 1 b 2 c 3 x 4 y 5 z 6}
94 SELECT tabc.a, txyz.x, tboth.a, tboth.x, * FROM tabc, txyz, tboth;
96 } {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}
99 SELECT * FROM v1 ORDER BY 2;
101 } {a 1 x 4 a:1 1 b 2 c 3 x:1 4 y 5 z 6}
102 do_test colname-2.9 {
104 SELECT * FROM v2 ORDER BY 2;
106 } {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}
109 # Tests for short=OFF and full=OFF
111 do_test colname-3.1 {
113 PRAGMA short_column_names=OFF;
114 PRAGMA full_column_names=OFF;
115 CREATE VIEW v3 AS SELECT tabC.a, txyZ.x, *
116 FROM tabc, txyz ORDER BY 1 LIMIT 1;
117 CREATE VIEW v4 AS SELECT tabC.a, txyZ.x, tboTh.a, tbotH.x, *
118 FROM tabc, txyz, tboth ORDER BY 1 LIMIT 1;
124 do_test colname-3.2 {
126 SELECT Tabc.a, tAbc.b, taBc.c FROM tabc
128 } {Tabc.a 1 tAbc.b 2 taBc.c 3}
129 do_test colname-3.3 {
131 SELECT +tabc.a, -tabc.b, tabc.c FROM tabc
133 } {+tabc.a 1 -tabc.b -2 tabc.c 3}
134 do_test colname-3.4 {
136 SELECT +tabc.a AS AAA, -tabc.b AS BBB, tabc.c CCC FROM tabc
138 } {AAA 1 BBB -2 CCC 3}
139 do_test colname-3.5 {
141 SELECT Tabc.a, Txyz.x, * FROM tabc, txyz;
143 } {Tabc.a 1 Txyz.x 4 a 1 b 2 c 3 x 4 y 5 z 6}
144 do_test colname-3.6 {
146 SELECT tabc.*, txyz.* FROM tabc, txyz;
148 } {a 1 b 2 c 3 x 4 y 5 z 6}
149 do_test colname-3.7 {
151 SELECT * FROM tabc, txyz, tboth;
153 } {a 11 b 12 c 13 x 14 y 15 z 16 a 11 b 12 c 13 x 14 y 15 z 16}
154 do_test colname-3.8 {
156 SELECT v1.a, * FROM v1 ORDER BY 2;
158 } {v1.a 1 a 1 x 4 a:1 1 b 2 c 3 x:1 4 y 5 z 6}
159 do_test colname-3.9 {
161 SELECT * FROM v2 ORDER BY 2;
163 } {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}
164 do_test colname-3.10 {
166 SELECT * FROM v3 ORDER BY 2;
168 } {a 1 x 4 a:1 1 b 2 c 3 x:1 4 y 5 z 6}
169 do_test colname-3.11 {
171 SELECT * FROM v4 ORDER BY 2;
173 } {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}
175 # Test for short=OFF and full=ON
177 do_test colname-4.1 {
179 PRAGMA short_column_names=OFF;
180 PRAGMA full_column_names=ON;
181 CREATE VIEW v5 AS SELECT tabC.a, txyZ.x, *
182 FROM tabc, txyz ORDER BY 1 LIMIT 1;
183 CREATE VIEW v6 AS SELECT tabC.a, txyZ.x, tboTh.a, tbotH.x, *
184 FROM tabc, txyz, tboth ORDER BY 1 LIMIT 1;
189 } {tabc.a 1 tabc.b 2 tabc.c 3}
190 do_test colname-4.2 {
192 SELECT Tabc.a, tAbc.b, taBc.c FROM tabc
194 } {tabc.a 1 tabc.b 2 tabc.c 3}
195 do_test colname-4.3 {
197 SELECT +tabc.a, -tabc.b, tabc.c FROM tabc
199 } {+tabc.a 1 -tabc.b -2 tabc.c 3}
200 do_test colname-4.4 {
202 SELECT +tabc.a AS AAA, -tabc.b AS BBB, tabc.c CCC FROM tabc
204 } {AAA 1 BBB -2 CCC 3}
205 do_test colname-4.5 {
207 SELECT Tabc.a, Txyz.x, * FROM tabc, txyz;
209 } {tabc.a 1 txyz.x 4 tabc.a 1 tabc.b 2 tabc.c 3 txyz.x 4 txyz.y 5 txyz.z 6}
210 do_test colname-4.6 {
212 SELECT tabc.*, txyz.* FROM tabc, txyz;
214 } {tabc.a 1 tabc.b 2 tabc.c 3 txyz.x 4 txyz.y 5 txyz.z 6}
215 do_test colname-4.7 {
217 SELECT * FROM tabc, txyz, tboth;
219 } {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}
220 do_test colname-4.8 {
222 SELECT * FROM v1 ORDER BY 2;
224 } {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}
225 do_test colname-4.9 {
227 SELECT * FROM v2 ORDER BY 2;
229 } {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}
230 do_test colname-4.10 {
232 SELECT * FROM v3 ORDER BY 2;
234 } {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}
235 do_test colname-4.11 {
237 SELECT * FROM v4 ORDER BY 2;
239 } {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}
240 do_test colname-4.12 {
242 SELECT * FROM v5 ORDER BY 2;
244 } {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}
245 do_test colname-4.13 {
247 SELECT * FROM v6 ORDER BY 2;
249 } {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}
252 do_test colname-5.1 {
254 SELECT x.* FROM sqlite_master X LIMIT 1;
256 } {table tabc tabc x {CREATE TABLE tabc(a,b,c)}}
258 # ticket #3370, #3371, #3372
260 do_test colname-6.1 {
264 CREATE TABLE t6(a, ['a'], ["a"], "[a]", [`a`]);
265 INSERT INTO t6 VALUES(1,2,3,4,5);
267 execsql2 {SELECT * FROM t6}
268 } {a 1 'a' 2 {"a"} 3 {[a]} 4 `a` 5}
269 do_test colname-6.2 {
270 execsql2 {SELECT ['a'], [`a`], "[a]", [a], ["a"] FROM t6}
271 } {'a' 2 `a` 5 {[a]} 4 a 1 {"a"} 3}
272 do_test colname-6.3 {
273 execsql2 {SELECT "'a'", "`a`", "[a]", "a", """a""" FROM t6}
274 } {'a' 2 `a` 5 {[a]} 4 a 1 {"a"} 3}
275 do_test colname-6.4 {
276 execsql2 {SELECT `'a'`, ```a```, `[a]`, `a`, `"a"` FROM t6}
277 } {'a' 2 `a` 5 {[a]} 4 a 1 {"a"} 3}
278 do_test colname-6.11 {
279 execsql2 {SELECT a, max(a) AS m FROM t6}
281 do_test colname-6.12 {
282 execsql2 {SELECT `a`, max(a) AS m FROM t6}
284 do_test colname-6.13 {
285 execsql2 {SELECT "a", max(a) AS m FROM t6}
287 do_test colname-6.14 {
288 execsql2 {SELECT [a], max(a) AS m FROM t6}
290 do_test colname-6.15 {
291 execsql2 {SELECT t6.a, max(a) AS m FROM t6}
293 do_test colname-6.16 {
294 execsql2 {SELECT ['a'], max(['a']) AS m FROM t6}
296 do_test colname-6.17 {
297 execsql2 {SELECT ["a"], max(["a"]) AS m FROM t6}
299 do_test colname-6.18 {
300 execsql2 {SELECT "[a]", max("[a]") AS m FROM t6}
302 do_test colname-6.19 {
303 execsql2 {SELECT "`a`", max([`a`]) AS m FROM t6}
308 # We cannot find anything wrong, but it never hurts to add another
311 do_test colname-7.1 {
313 CREATE TABLE t7(x INTEGER PRIMARY KEY, y);
314 INSERT INTO t7 VALUES(1,2);
316 execsql2 {SELECT rowid, * FROM t7}
319 # Tickets #3893 and #3984. (Same problem; independently reported)
321 do_test colname-8.1 {
323 CREATE TABLE "t3893"("x");
324 INSERT INTO t3893 VALUES(123);
325 SELECT "y"."x" FROM (SELECT "x" FROM "t3893") AS "y";