Bare identifiers in ORDER BY clauses bind more tightly to output column name,

but identifiers in expressions bind more tightly to input column names.
This is a compromise between SQL92 and SQL99 behavior and is what
PostgreSQL and MS-SQL do.  Ticket [f617ea3125e9c].

FossilOrigin-Name: c78b357c00a35ed48ce2ffbc041de8d22570d1e2
This commit is contained in:
drh 2013-08-15 20:24:27 +00:00
parent fc7df53aee
commit e35463b312
6 changed files with 143 additions and 29 deletions

@ -1,5 +1,5 @@
C Make\sit\seasy\sto\sattach\sa\sdebugger\sthe\stest\sfixture\sprocess\sprior\sto\sany\stests\sbeing\srun.
D 2013-08-15T20:05:03.202
C Bare\sidentifiers\sin\sORDER\sBY\sclauses\sbind\smore\stightly\sto\soutput\scolumn\sname,\nbut\sidentifiers\sin\sexpressions\sbind\smore\stightly\sto\sinput\scolumn\snames.\nThis\sis\sa\scompromise\sbetween\sSQL92\sand\sSQL99\sbehavior\sand\sis\swhat\nPostgreSQL\sand\sMS-SQL\sdo.\s\sTicket\s[f617ea3125e9c].
D 2013-08-15T20:24:27.463
F Makefile.arm-wince-mingw32ce-gcc d6df77f1f48d690bd73162294bbba7f59507c72f
F Makefile.in 5e41da95d92656a5004b03d3576e8b226858a28e
F Makefile.linux-gcc 91d710bdc4998cb015f39edf3cb314ec4f4d7e23
@ -214,14 +214,14 @@ F src/pragma.c 590c75750d93ec5a1f903e4bb0dc6d2a0845bf8b
F src/prepare.c fa6988589f39af8504a61731614cd4f6ae71554f
F src/printf.c 41c49dac366a3a411190001a8ab495fa8887974e
F src/random.c cd4a67b3953b88019f8cd4ccd81394a8ddfaba50
F src/resolve.c 94a08f37c04352bbdd4a91b335e1a4feb256a3c7
F src/resolve.c 2a760f369ddbcd951f176556c8ec05be04cdd0da
F src/rowset.c 64655f1a627c9c212d9ab497899e7424a34222e0
F src/select.c 8b148eb851f384412aea57091659d14b369918ca
F src/shell.c 927e17b37b63b24461e372d982138fb22c4df321
F src/sqlite.h.in bd1451ba1ab681022a53bccc3c39580ba094a3ff
F src/sqlite3.rc fea433eb0a59f4c9393c8e6d76a6e2596b1fe0c0
F src/sqlite3ext.h 886f5a34de171002ad46fae8c36a7d8051c190fc
F src/sqliteInt.h ac5de15640d7a5d6ea46724fe3e0ffd39af0ed12
F src/sqliteInt.h b2a4e9a85e4bb49c1537fe7fc6532cd7ebe82aa0
F src/sqliteLimit.h 164b0e6749d31e0daa1a4589a169d31c0dec7b3d
F src/status.c 7ac05a5c7017d0b9f0b4bcd701228b784f987158
F src/table.c 2cd62736f845d82200acfa1287e33feb3c15d62e
@ -733,7 +733,7 @@ F test/regexp1.test 497ea812f264d12b6198d6e50a76be4a1973a9d8
F test/reindex.test 44edd3966b474468b823d481eafef0c305022254
F test/releasetest.mk 2eced2f9ae701fd0a29e714a241760503ccba25a
F test/releasetest.tcl 06d289d8255794073a58d2850742f627924545ce
F test/resolver01.test d1b487fc567bdb70b5dd09ccaaa877ddc61a233e
F test/resolver01.test a98ed8a2e9f78600155d783389ad4e6537010285
F test/rollback.test a1b4784b864331eae8b2a98c189efa2a8b11ff07
F test/rowhash.test 0bc1d31415e4575d10cacf31e1a66b5cc0f8be81
F test/rowid.test f777404492adb0e00868fd706a3721328fd3af48
@ -906,7 +906,7 @@ F test/tkt2686.test 6ee01c9b9e9c48f6d3a1fdd553b1cc4258f903d6
F test/tkt2767.test 569000d842678f9cf2db7e0d1b27cbc9011381b0
F test/tkt2817.test f31839e01f4243cff7399ef654d3af3558cb8d8d
F test/tkt2820.test 39940276b3436d125deb7d8ebeee053e4cf13213
F test/tkt2822.test c3589494fba643e039bcf0bfde7554ff6028406d
F test/tkt2822.test f391776423a7c0d0949edfce375708bfb0f3141e
F test/tkt2832.test a9b0b74a02dca166a04d9e37739c414b10929caa
F test/tkt2854.test e432965db29e27e16f539b2ba7f502eb2ccc49af
F test/tkt2920.test a8737380e4ae6424e00c0273dc12775704efbebf
@ -1105,7 +1105,7 @@ F tool/warnings-clang.sh f6aa929dc20ef1f856af04a730772f59283631d4
F tool/warnings.sh fbc018d67fd7395f440c28f33ef0f94420226381
F tool/wherecosttest.c f407dc4c79786982a475261866a161cd007947ae
F tool/win/sqlite.vsix 97894c2790eda7b5bce3cc79cb2a8ec2fde9b3ac
P f30abdf9d814d6c75bf1c803054737c737ad636f c23acba11bfefc019b5945cfb345f9afcf4b6242
R fb4db235176e52d42891fba292ddbfa5
U mistachkin
Z 4d072d8f2cb243e6b9c13cb11a27b554
P 53cd9ebfaf401c7932bf591e134a527c9962b88e
R b873391074dfe27843eed5ca71b0596f
U drh
Z 52475f320db5f901cc1dc06cbb7fef10

@ -1 +1 @@
53cd9ebfaf401c7932bf591e134a527c9962b88e
c78b357c00a35ed48ce2ffbc041de8d22570d1e2

@ -55,7 +55,7 @@ static void incrAggFunctionDepth(Expr *pExpr, int N){
** column reference is so that the column reference will be recognized as
** usable by indices within the WHERE clause processing logic.
**
** Hack: The TK_AS operator is inhibited if zType[0]=='G'. This means
** The TK_AS operator is inhibited if zType[0]=='G'. This means
** that in a GROUP BY clause, the expression is evaluated twice. Hence:
**
** SELECT random()%5 AS x, count(*) FROM tab GROUP BY x
@ -65,8 +65,9 @@ static void incrAggFunctionDepth(Expr *pExpr, int N){
** SELECT random()%5 AS x, count(*) FROM tab GROUP BY random()%5
**
** The result of random()%5 in the GROUP BY clause is probably different
** from the result in the result-set. We might fix this someday. Or
** then again, we might not...
** from the result in the result-set. On the other hand Standard SQL does
** not allow the GROUP BY clause to contain references to result-set columns.
** So this should never come up in well-formed queries.
**
** If the reference is followed by a COLLATE operator, then make sure
** the COLLATE operator is preserved. For example:
@ -396,10 +397,16 @@ static int lookupName(
** forms the result set entry ("a+b" in the example) and return immediately.
** Note that the expression in the result set should have already been
** resolved by the time the WHERE clause is resolved.
**
** The ability to use an output result-set column in the WHERE, GROUP BY,
** or HAVING clauses, or as part of a larger expression in the ORDRE BY
** clause is not standard SQL. This is a (goofy) SQLite extension, that
** is supported for backwards compatibility only. TO DO: Issue a warning
** on sqlite3_log() whenever the capability is used.
*/
if( (pEList = pNC->pEList)!=0
&& zTab==0
&& ((pNC->ncFlags & NC_AsMaybe)==0 || cnt==0)
&& cnt==0
){
for(j=0; j<pEList->nExpr; j++){
char *zAs = pEList->a[j].zName;
@ -961,7 +968,7 @@ static int resolveCompoundOrderBy(
/*
** Check every term in the ORDER BY or GROUP BY clause pOrderBy of
** the SELECT statement pSelect. If any term is reference to a
** result set expression (as determined by the ExprList.a.iCol field)
** result set expression (as determined by the ExprList.a.iOrderByCol field)
** then convert that term into a copy of the corresponding result set
** column.
**
@ -1035,7 +1042,8 @@ static int resolveOrderGroupBy(
pParse = pNC->pParse;
for(i=0, pItem=pOrderBy->a; i<pOrderBy->nExpr; i++, pItem++){
Expr *pE = pItem->pExpr;
iCol = resolveAsName(pParse, pSelect->pEList, pE);
Expr *pE2 = sqlite3ExprSkipCollate(pE);
iCol = resolveAsName(pParse, pSelect->pEList, pE2);
if( iCol>0 ){
/* If an AS-name match is found, mark this ORDER BY column as being
** a copy of the iCol-th result-set column. The subsequent call to
@ -1044,7 +1052,7 @@ static int resolveOrderGroupBy(
pItem->iOrderByCol = (u16)iCol;
continue;
}
if( sqlite3ExprIsInteger(sqlite3ExprSkipCollate(pE), &iCol) ){
if( sqlite3ExprIsInteger(pE2, &iCol) ){
/* The ORDER BY term is an integer constant. Again, set the column
** number so that sqlite3ResolveOrderGroupBy() will convert the
** order-by term to a copy of the result-set expression */
@ -1196,10 +1204,8 @@ static int resolveSelectStep(Walker *pWalker, Select *p){
** re-evaluated for each reference to it.
*/
sNC.pEList = p->pEList;
sNC.ncFlags |= NC_AsMaybe;
if( sqlite3ResolveExprNames(&sNC, p->pHaving) ) return WRC_Abort;
if( sqlite3ResolveExprNames(&sNC, p->pWhere) ) return WRC_Abort;
sNC.ncFlags &= ~NC_AsMaybe;
/* The ORDER BY and GROUP BY clauses may not refer to terms in
** outer queries

@ -2021,9 +2021,7 @@ struct NameContext {
#define NC_HasAgg 0x02 /* One or more aggregate functions seen */
#define NC_IsCheck 0x04 /* True if resolving names in a CHECK constraint */
#define NC_InAggFunc 0x08 /* True if analyzing arguments to an agg func */
#define NC_AsMaybe 0x10 /* Resolve to AS terms of the result set only
** if no other resolution is available */
#define NC_PartIdx 0x20 /* True if resolving a partial index WHERE */
#define NC_PartIdx 0x10 /* True if resolving a partial index WHERE */
/*
** An instance of the following structure contains all information

@ -13,10 +13,18 @@
# figures out what identifiers in the SQL statement refer to) that
# were fixed by ticket [2500cdb9be]
#
# See also tickets [1c69be2daf] and [f617ea3125] from 2013-08-14.
#
set testdir [file dirname $argv0]
source $testdir/tester.tcl
# "ORDER BY y" binds to the output result-set column named "y"
# if available. If no output column is named "y", then try to
# bind against an input column named "y".
#
# This is classical SQL92 behavior.
#
do_test resolver01-1.1 {
catchsql {
CREATE TABLE t1(x, y); INSERT INTO t1 VALUES(11,22);
@ -25,15 +33,120 @@ do_test resolver01-1.1 {
}
} {0 1}
do_test resolver01-1.2 {
catchsql {
SELECT 1 AS yy FROM t1, t2 ORDER BY y;
}
} {1 {ambiguous column name: y}}
do_test resolver01-1.3 {
catchsql {
CREATE TABLE t3(x,y); INSERT INTO t3 VALUES(11,44),(33,22);
SELECT x AS y FROM t3 ORDER BY y;
}
} {0 {11 33}}
do_test resolver01-1.4 {
catchsql {
SELECT x AS yy FROM t3 ORDER BY y;
}
} {0 {33 11}}
# SQLite allows the WHERE clause to reference output columns if there is
# no other way to resolve the name.
#
do_test resolver01-1.5 {
catchsql {
SELECT x AS yy FROM t3 ORDER BY yy;
}
} {0 {11 33}}
do_test resolver01-1.6 {
catchsql {
SELECT x AS yy FROM t3 ORDER BY 1;
}
} {0 {11 33}}
# The "ORDER BY y COLLATE nocase" form works the same as "ORDER BY y".
# The "y" binds more tightly to output columns than to input columns.
#
# This is for compatibility with SQL92 and with historical SQLite behavior.
# Note that PostgreSQL considers "y COLLATE nocase" to be an expression
# and thus PostgreSQL treats this case as if it where the 3.x case below.
#
do_test resolver01-2.1 {
catchsql {
SELECT 2 AS y FROM t1, t2 ORDER BY y COLLATE nocase;
}
} {0 2}
do_test resolver01-1.3 {
do_test resolver01-2.2 {
catchsql {
SELECT 2 AS yy FROM t1, t2 ORDER BY y COLLATE nocase;
}
} {1 {ambiguous column name: y}}
do_test resolver01-2.3 {
catchsql {
SELECT x AS y FROM t3 ORDER BY y COLLATE nocase;
}
} {0 {11 33}}
do_test resolver01-2.4 {
catchsql {
SELECT x AS yy FROM t3 ORDER BY y COLLATE nocase;
}
} {0 {33 11}}
do_test resolver01-2.5 {
catchsql {
SELECT x AS yy FROM t3 ORDER BY yy COLLATE nocase;
}
} {0 {11 33}}
do_test resolver01-2.6 {
catchsql {
SELECT x AS yy FROM t3 ORDER BY 1 COLLATE nocase;
}
} {0 {11 33}}
# But if the form is "ORDER BY expr" then bind more tightly to the
# the input column names and only use the output column names if no
# input column name matches.
#
# This is SQL99 behavior, as implemented by PostgreSQL and MS-SQL.
# Note that Oracle works differently.
#
do_test resolver01-3.1 {
catchsql {
SELECT 3 AS y FROM t1, t2 ORDER BY +y;
}
} {0 3}
} {1 {ambiguous column name: y}}
do_test resolver01-3.2 {
catchsql {
SELECT 2 AS yy FROM t1, t2 ORDER BY +y;
}
} {1 {ambiguous column name: y}}
do_test resolver01-3.3 {
catchsql {
SELECT x AS y FROM t3 ORDER BY +y;
}
} {0 {33 11}}
do_test resolver01-3.4 {
catchsql {
SELECT x AS yy FROM t3 ORDER BY +y;
}
} {0 {33 11}}
do_test resolver01-3.5 {
catchsql {
SELECT x AS yy FROM t3 ORDER BY +yy
}
} {0 {11 33}}
# This is the test case given in ticket [f617ea3125e9] (with table name
# changed from "t1" to "t4". The behavior of (1) and (3) match with
# PostgreSQL, but we intentionally break with PostgreSQL to provide
# SQL92 behavior for case (2).
#
do_execsql_test resolver01-4.1 {
CREATE TABLE t4(m CHAR(2));
INSERT INTO t4 VALUES('az');
INSERT INTO t4 VALUES('by');
INSERT INTO t4 VALUES('cx');
SELECT '1', substr(m,2) AS m FROM t4 ORDER BY m;
SELECT '2', substr(m,2) AS m FROM t4 ORDER BY m COLLATE binary;
SELECT '3', substr(m,2) AS m FROM t4 ORDER BY lower(m);
} {1 x 1 y 1 z 2 x 2 y 2 z 3 z 3 y 3 x}
finish_test

@ -208,15 +208,12 @@ do_test tkt2822-5.4 {
# In "ORDER BY +b" the term is now an expression rather than
# a label. It therefore matches by rule (3) instead of rule (2).
#
# 2013-04-13: This is busted. Changed to conform to PostgreSQL and
# MySQL and Oracle behavior.
#
do_test tkt2822-5.5 {
execsql {
SELECT a AS b FROM t3 ORDER BY +b;
}
} {1 9}
} {9 1}
# Tests for rule 2 in compound queries
#