1a3a5bd9bSdrh# 2013-04-13 2a3a5bd9bSdrh# 3a3a5bd9bSdrh# The author disclaims copyright to this source code. In place of 4a3a5bd9bSdrh# a legal notice, here is a blessing: 5a3a5bd9bSdrh# 6a3a5bd9bSdrh# May you do good and not evil. 7a3a5bd9bSdrh# May you find forgiveness for yourself and forgive others. 8a3a5bd9bSdrh# May you share freely, never taking more than you give. 9a3a5bd9bSdrh# 10a3a5bd9bSdrh#*********************************************************************** 11a3a5bd9bSdrh# 12a3a5bd9bSdrh# This file tests features of the name resolver (the component that 13a3a5bd9bSdrh# figures out what identifiers in the SQL statement refer to) that 14*41148f83Sdrh# were fixed by ticket [2500cdb9be]. 15a3a5bd9bSdrh# 16e35463b3Sdrh# See also tickets [1c69be2daf] and [f617ea3125] from 2013-08-14. 17e35463b3Sdrh# 18*41148f83Sdrh# Also a fuzzer-discovered problem on 2015-04-23. 19*41148f83Sdrh# 20a3a5bd9bSdrh 21a3a5bd9bSdrhset testdir [file dirname $argv0] 22a3a5bd9bSdrhsource $testdir/tester.tcl 23a3a5bd9bSdrh 24e35463b3Sdrh# "ORDER BY y" binds to the output result-set column named "y" 25e35463b3Sdrh# if available. If no output column is named "y", then try to 26e35463b3Sdrh# bind against an input column named "y". 27e35463b3Sdrh# 28e35463b3Sdrh# This is classical SQL92 behavior. 29e35463b3Sdrh# 30a3a5bd9bSdrhdo_test resolver01-1.1 { 31a3a5bd9bSdrh catchsql { 32a3a5bd9bSdrh CREATE TABLE t1(x, y); INSERT INTO t1 VALUES(11,22); 33a3a5bd9bSdrh CREATE TABLE t2(y, z); INSERT INTO t2 VALUES(33,44); 34a3a5bd9bSdrh SELECT 1 AS y FROM t1, t2 ORDER BY y; 35a3a5bd9bSdrh } 36a3a5bd9bSdrh} {0 1} 37a3a5bd9bSdrhdo_test resolver01-1.2 { 38a3a5bd9bSdrh catchsql { 39e35463b3Sdrh SELECT 1 AS yy FROM t1, t2 ORDER BY y; 40e35463b3Sdrh } 41e35463b3Sdrh} {1 {ambiguous column name: y}} 42e35463b3Sdrhdo_test resolver01-1.3 { 43e35463b3Sdrh catchsql { 44e35463b3Sdrh CREATE TABLE t3(x,y); INSERT INTO t3 VALUES(11,44),(33,22); 45e35463b3Sdrh SELECT x AS y FROM t3 ORDER BY y; 46e35463b3Sdrh } 47e35463b3Sdrh} {0 {11 33}} 48e35463b3Sdrhdo_test resolver01-1.4 { 49e35463b3Sdrh catchsql { 50e35463b3Sdrh SELECT x AS yy FROM t3 ORDER BY y; 51e35463b3Sdrh } 52e35463b3Sdrh} {0 {33 11}} 53e35463b3Sdrh 54e35463b3Sdrh# SQLite allows the WHERE clause to reference output columns if there is 55e35463b3Sdrh# no other way to resolve the name. 56e35463b3Sdrh# 57e35463b3Sdrhdo_test resolver01-1.5 { 58e35463b3Sdrh catchsql { 59e35463b3Sdrh SELECT x AS yy FROM t3 ORDER BY yy; 60e35463b3Sdrh } 61e35463b3Sdrh} {0 {11 33}} 62e35463b3Sdrhdo_test resolver01-1.6 { 63e35463b3Sdrh catchsql { 64e35463b3Sdrh SELECT x AS yy FROM t3 ORDER BY 1; 65e35463b3Sdrh } 66e35463b3Sdrh} {0 {11 33}} 67e35463b3Sdrh 68e35463b3Sdrh# The "ORDER BY y COLLATE nocase" form works the same as "ORDER BY y". 69e35463b3Sdrh# The "y" binds more tightly to output columns than to input columns. 70e35463b3Sdrh# 71e35463b3Sdrh# This is for compatibility with SQL92 and with historical SQLite behavior. 72e35463b3Sdrh# Note that PostgreSQL considers "y COLLATE nocase" to be an expression 73e35463b3Sdrh# and thus PostgreSQL treats this case as if it where the 3.x case below. 74e35463b3Sdrh# 75e35463b3Sdrhdo_test resolver01-2.1 { 76e35463b3Sdrh catchsql { 77a3a5bd9bSdrh SELECT 2 AS y FROM t1, t2 ORDER BY y COLLATE nocase; 78a3a5bd9bSdrh } 79a3a5bd9bSdrh} {0 2} 80e35463b3Sdrhdo_test resolver01-2.2 { 81e35463b3Sdrh catchsql { 82e35463b3Sdrh SELECT 2 AS yy FROM t1, t2 ORDER BY y COLLATE nocase; 83e35463b3Sdrh } 84e35463b3Sdrh} {1 {ambiguous column name: y}} 85e35463b3Sdrhdo_test resolver01-2.3 { 86e35463b3Sdrh catchsql { 87e35463b3Sdrh SELECT x AS y FROM t3 ORDER BY y COLLATE nocase; 88e35463b3Sdrh } 89e35463b3Sdrh} {0 {11 33}} 90e35463b3Sdrhdo_test resolver01-2.4 { 91e35463b3Sdrh catchsql { 92e35463b3Sdrh SELECT x AS yy FROM t3 ORDER BY y COLLATE nocase; 93e35463b3Sdrh } 94e35463b3Sdrh} {0 {33 11}} 95e35463b3Sdrhdo_test resolver01-2.5 { 96e35463b3Sdrh catchsql { 97e35463b3Sdrh SELECT x AS yy FROM t3 ORDER BY yy COLLATE nocase; 98e35463b3Sdrh } 99e35463b3Sdrh} {0 {11 33}} 100e35463b3Sdrhdo_test resolver01-2.6 { 101e35463b3Sdrh catchsql { 102e35463b3Sdrh SELECT x AS yy FROM t3 ORDER BY 1 COLLATE nocase; 103e35463b3Sdrh } 104e35463b3Sdrh} {0 {11 33}} 105e35463b3Sdrh 106e35463b3Sdrh# But if the form is "ORDER BY expr" then bind more tightly to the 107e35463b3Sdrh# the input column names and only use the output column names if no 108e35463b3Sdrh# input column name matches. 109e35463b3Sdrh# 110e35463b3Sdrh# This is SQL99 behavior, as implemented by PostgreSQL and MS-SQL. 111e35463b3Sdrh# Note that Oracle works differently. 112e35463b3Sdrh# 113e35463b3Sdrhdo_test resolver01-3.1 { 114a3a5bd9bSdrh catchsql { 115a3a5bd9bSdrh SELECT 3 AS y FROM t1, t2 ORDER BY +y; 116a3a5bd9bSdrh } 117e35463b3Sdrh} {1 {ambiguous column name: y}} 118e35463b3Sdrhdo_test resolver01-3.2 { 119e35463b3Sdrh catchsql { 120e35463b3Sdrh SELECT 2 AS yy FROM t1, t2 ORDER BY +y; 121e35463b3Sdrh } 122e35463b3Sdrh} {1 {ambiguous column name: y}} 123e35463b3Sdrhdo_test resolver01-3.3 { 124e35463b3Sdrh catchsql { 125e35463b3Sdrh SELECT x AS y FROM t3 ORDER BY +y; 126e35463b3Sdrh } 127e35463b3Sdrh} {0 {33 11}} 128e35463b3Sdrhdo_test resolver01-3.4 { 129e35463b3Sdrh catchsql { 130e35463b3Sdrh SELECT x AS yy FROM t3 ORDER BY +y; 131e35463b3Sdrh } 132e35463b3Sdrh} {0 {33 11}} 133e35463b3Sdrhdo_test resolver01-3.5 { 134e35463b3Sdrh catchsql { 135e35463b3Sdrh SELECT x AS yy FROM t3 ORDER BY +yy 136e35463b3Sdrh } 137e35463b3Sdrh} {0 {11 33}} 138a3a5bd9bSdrh 139e35463b3Sdrh# This is the test case given in ticket [f617ea3125e9] (with table name 140e35463b3Sdrh# changed from "t1" to "t4". The behavior of (1) and (3) match with 141e35463b3Sdrh# PostgreSQL, but we intentionally break with PostgreSQL to provide 142e35463b3Sdrh# SQL92 behavior for case (2). 143e35463b3Sdrh# 144e35463b3Sdrhdo_execsql_test resolver01-4.1 { 145e35463b3Sdrh CREATE TABLE t4(m CHAR(2)); 146e35463b3Sdrh INSERT INTO t4 VALUES('az'); 147e35463b3Sdrh INSERT INTO t4 VALUES('by'); 148e35463b3Sdrh INSERT INTO t4 VALUES('cx'); 149e35463b3Sdrh SELECT '1', substr(m,2) AS m FROM t4 ORDER BY m; 150e35463b3Sdrh SELECT '2', substr(m,2) AS m FROM t4 ORDER BY m COLLATE binary; 151e35463b3Sdrh SELECT '3', substr(m,2) AS m FROM t4 ORDER BY lower(m); 152e35463b3Sdrh} {1 x 1 y 1 z 2 x 2 y 2 z 3 z 3 y 3 x} 153a3a5bd9bSdrh 1540af16ab2Sdrh########################################################################## 1550af16ab2Sdrh# Test cases for ticket [1c69be2dafc28]: Make sure the GROUP BY binds 1560af16ab2Sdrh# more tightly to the input tables in all cases. 1570af16ab2Sdrh# 1580af16ab2Sdrh# This first case case has been wrong in SQLite for time out of mind. 1590af16ab2Sdrh# For SQLite version 3.7.17 the answer was two rows, which is wrong. 1600af16ab2Sdrh# 1610af16ab2Sdrhdo_execsql_test resolver01-5.1 { 1620af16ab2Sdrh CREATE TABLE t5(m CHAR(2)); 1630af16ab2Sdrh INSERT INTO t5 VALUES('ax'); 1640af16ab2Sdrh INSERT INTO t5 VALUES('bx'); 1650af16ab2Sdrh INSERT INTO t5 VALUES('cy'); 1660af16ab2Sdrh SELECT count(*), substr(m,2,1) AS m FROM t5 GROUP BY m ORDER BY 1, 2; 1670af16ab2Sdrh} {1 x 1 x 1 y} 1680af16ab2Sdrh 1690af16ab2Sdrh# This case is unambiguous and has always been correct. 1700af16ab2Sdrh# 1710af16ab2Sdrhdo_execsql_test resolver01-5.2 { 1720af16ab2Sdrh SELECT count(*), substr(m,2,1) AS mx FROM t5 GROUP BY m ORDER BY 1, 2; 1730af16ab2Sdrh} {1 x 1 x 1 y} 1740af16ab2Sdrh 1750af16ab2Sdrh# This case is not allowed in standard SQL, but SQLite allows and does 1760af16ab2Sdrh# the sensible thing. 1770af16ab2Sdrh# 1780af16ab2Sdrhdo_execsql_test resolver01-5.3 { 1790af16ab2Sdrh SELECT count(*), substr(m,2,1) AS mx FROM t5 GROUP BY mx ORDER BY 1, 2; 1800af16ab2Sdrh} {1 y 2 x} 1810af16ab2Sdrhdo_execsql_test resolver01-5.4 { 1820af16ab2Sdrh SELECT count(*), substr(m,2,1) AS mx FROM t5 1830af16ab2Sdrh GROUP BY substr(m,2,1) ORDER BY 1, 2; 1840af16ab2Sdrh} {1 y 2 x} 1850af16ab2Sdrh 1860af16ab2Sdrh# These test case weere provided in the 2013-08-14 email from Rob Golsteijn 1870af16ab2Sdrh# that originally reported the problem of ticket [1c69be2dafc28]. 1880af16ab2Sdrh# 1890af16ab2Sdrhdo_execsql_test resolver01-6.1 { 1900af16ab2Sdrh CREATE TABLE t61(name); 1910af16ab2Sdrh SELECT min(name) FROM t61 GROUP BY lower(name); 1920af16ab2Sdrh} {} 1930af16ab2Sdrhdo_execsql_test resolver01-6.2 { 1940af16ab2Sdrh SELECT min(name) AS name FROM t61 GROUP BY lower(name); 1950af16ab2Sdrh} {} 1960af16ab2Sdrhdo_execsql_test resolver01-6.3 { 1970af16ab2Sdrh CREATE TABLE t63(name); 1980af16ab2Sdrh INSERT INTO t63 VALUES (NULL); 1990af16ab2Sdrh INSERT INTO t63 VALUES ('abc'); 2000af16ab2Sdrh SELECT count(), 2010af16ab2Sdrh NULLIF(name,'abc') AS name 2020af16ab2Sdrh FROM t63 2030af16ab2Sdrh GROUP BY lower(name); 2040af16ab2Sdrh} {1 {} 1 {}} 2050af16ab2Sdrh 206*41148f83Sdrhdo_execsql_test resolver01-7.1 { 207*41148f83Sdrh SELECT 2 AS x WHERE (SELECT x AS y WHERE 3>y); 208*41148f83Sdrh} {2} 209*41148f83Sdrhdo_execsql_test resolver01-7.2 { 210*41148f83Sdrh SELECT 2 AS x WHERE (SELECT x AS y WHERE 1>y); 211*41148f83Sdrh} {} 2120af16ab2Sdrh 2130af16ab2Sdrh 2140af16ab2Sdrh 2150af16ab2Sdrh 216a3a5bd9bSdrhfinish_test 217