Skip to content

Commit 111e220

Browse files
author
D. Richard Hipp
committed
Improvement to the way that affinity is determined for columns of a
compound subquery. The affinity is the affinity of the left-most arm of the compound subquery that has an affinity other than NONE, adjusted to accommodate the data types coming out of the other arms.
2 parents 6027c7b + 246bbfc commit 111e220

File tree

3 files changed

+91
-4
lines changed

3 files changed

+91
-4
lines changed

src/select.c

+9-4
Original file line numberDiff line numberDiff line change
@@ -2336,17 +2336,22 @@ void sqlite3SubqueryColumnTypes(
23362336
for(i=0, pCol=pTab->aCol; i<pTab->nCol; i++, pCol++){
23372337
const char *zType;
23382338
i64 n;
2339+
int m = 0;
2340+
Select *pS2 = pSelect;
23392341
pTab->tabFlags |= (pCol->colFlags & COLFLAG_NOINSERT);
23402342
p = a[i].pExpr;
23412343
/* pCol->szEst = ... // Column size est for SELECT tables never used */
23422344
pCol->affinity = sqlite3ExprAffinity(p);
2345+
while( pCol->affinity<=SQLITE_AFF_NONE && pS2->pNext!=0 ){
2346+
m |= sqlite3ExprDataType(pS2->pEList->a[i].pExpr);
2347+
pS2 = pS2->pNext;
2348+
pCol->affinity = sqlite3ExprAffinity(pS2->pEList->a[i].pExpr);
2349+
}
23432350
if( pCol->affinity<=SQLITE_AFF_NONE ){
23442351
pCol->affinity = aff;
23452352
}
2346-
if( pCol->affinity>=SQLITE_AFF_TEXT && pSelect->pNext ){
2347-
int m = 0;
2348-
Select *pS2;
2349-
for(m=0, pS2=pSelect->pNext; pS2; pS2=pS2->pNext){
2353+
if( pCol->affinity>=SQLITE_AFF_TEXT && (pS2->pNext || pS2!=pSelect) ){
2354+
for(pS2=pS2->pNext; pS2; pS2=pS2->pNext){
23502355
m |= sqlite3ExprDataType(pS2->pEList->a[i].pExpr);
23512356
}
23522357
if( pCol->affinity==SQLITE_AFF_TEXT && (m&0x01)!=0 ){

test/subquery.test

+59
Original file line numberDiff line numberDiff line change
@@ -651,5 +651,64 @@ do_eqp_test subquery-10.2 {
651651
# `--SEARCH t1 USING INDEX x12 (aa=?)
652652
#
653653

654+
#-----------------------------------------------------------------------------
655+
# 2024-04-25 Column affinities for columns of compound subqueries
656+
#
657+
reset_db
658+
sqlite3_test_control SQLITE_TESTCTRL_INTERNAL_FUNCTIONS db
659+
do_execsql_test subquery-11.1 {
660+
CREATE TABLE t1(ix INT, rx REAL, bx BLOB, tx TEXT, ax);
661+
INSERT INTO t1 VALUES(1,1.0,x'31','x',NULL);
662+
WITH c(a) AS (SELECT 'y' UNION SELECT tx FROM t1) SELECT affinity(a) FROM c;
663+
WITH c(a) AS (SELECT tx FROM t1 UNION SELECT 'y') SELECT affinity(a) FROM c;
664+
} {text text text text}
665+
do_execsql_test subquery-11.2 {
666+
WITH c(a) AS (SELECT 2 UNION SELECT tx FROM t1) SELECT affinity(a) FROM c;
667+
WITH c(a) AS (SELECT tx FROM t1 UNION SELECT 2) SELECT affinity(a) FROM c;
668+
} {blob blob blob blob}
669+
do_execsql_test subquery-11.3 {
670+
WITH c(a) AS (SELECT 2.0 UNION SELECT tx FROM t1) SELECT affinity(a) FROM c;
671+
WITH c(a) AS (SELECT tx FROM t1 UNION SELECT 2.0) SELECT affinity(a) FROM c;
672+
} {blob blob blob blob}
673+
do_execsql_test subquery-11.4 {
674+
WITH c(a) AS (SELECT null UNION SELECT tx FROM t1) SELECT affinity(a) FROM c;
675+
WITH c(a) AS (SELECT tx FROM t1 UNION SELECT null) SELECT affinity(a) FROM c;
676+
} {text text text text}
677+
do_execsql_test subquery-11.5 {
678+
WITH c(a) AS (SELECT x'32' UNION SELECT tx FROM t1) SELECT affinity(a) FROM c;
679+
WITH c(a) AS (SELECT tx FROM t1 UNION SELECT x'32') SELECT affinity(a) FROM c;
680+
} {text text text text}
681+
do_execsql_test subquery-11.6 {
682+
WITH c(a) AS (SELECT 3 UNION SELECT ix FROM t1) SELECT affinity(a) FROM c;
683+
WITH c(a) AS (SELECT ix FROM t1 UNION SELECT 3) SELECT affinity(a) FROM c;
684+
} {integer integer integer integer}
685+
do_execsql_test subquery-11.7 {
686+
WITH c(a) AS (SELECT 3.0 UNION SELECT ix FROM t1) SELECT affinity(a) FROM c;
687+
WITH c(a) AS (SELECT ix FROM t1 UNION SELECT 3.0) SELECT affinity(a) FROM c;
688+
} {integer integer integer integer}
689+
do_execsql_test subquery-11.8 {
690+
WITH c(a) AS (SELECT '3' UNION SELECT ix FROM t1) SELECT affinity(a) FROM c;
691+
WITH c(a) AS (SELECT ix FROM t1 UNION SELECT '3') SELECT affinity(a) FROM c;
692+
} {blob blob blob blob}
693+
do_execsql_test subquery-11.10 {
694+
WITH c(a) AS (SELECT x'32' UNION SELECT ix FROM t1) SELECT affinity(a) FROM c;
695+
WITH c(a) AS (SELECT ix FROM t1 UNION SELECT x'32') SELECT affinity(a) FROM c;
696+
} {integer integer integer integer}
697+
do_execsql_test subquery-11.11 {
698+
WITH c(a) AS (SELECT 4 UNION SELECT rx FROM t1) SELECT affinity(a) FROM c;
699+
WITH c(a) AS (SELECT rx FROM t1 UNION SELECT 4) SELECT affinity(a) FROM c;
700+
} {real real real real}
701+
do_execsql_test subquery-11.12 {
702+
WITH c(a) AS (SELECT '4' UNION SELECT rx FROM t1) SELECT affinity(a) FROM c;
703+
WITH c(a) AS (SELECT rx FROM t1 UNION SELECT '4') SELECT affinity(a) FROM c;
704+
} {blob blob blob blob}
705+
do_execsql_test subquery-11.13 {
706+
WITH c(a) AS (SELECT null UNION SELECT rx FROM t1) SELECT affinity(a) FROM c;
707+
WITH c(a) AS (SELECT rx FROM t1 UNION SELECT null) SELECT affinity(a) FROM c;
708+
} {real real real real}
709+
do_execsql_test subquery-11.14 {
710+
WITH c(a) AS (SELECT x'b4' UNION SELECT rx FROM t1) SELECT affinity(a) FROM c;
711+
WITH c(a) AS (SELECT rx FROM t1 UNION SELECT x'b4') SELECT affinity(a) FROM c;
712+
} {real real real real}
654713

655714
finish_test

test/view.test

+23
Original file line numberDiff line numberDiff line change
@@ -801,4 +801,27 @@ ifcapable schema_pragmas {
801801
} { 0 a INT 0 {} 0 1 b BLOB 0 {} 0 }
802802
}
803803

804+
#-----------------------------------------------------------------------
805+
# 2024-04-25 Trying to make type information on compound subqueries
806+
# more predictable and rational.
807+
#
808+
reset_db
809+
do_execsql_test view-31.1 {
810+
CREATE TABLE x2(b TEXT);
811+
CREATE TABLE x1(a TEXT);
812+
INSERT INTO x1 VALUES('123');
813+
-- Two queries get the same result even though the order of terms
814+
-- in the CTE is reversed
815+
WITH c(x) AS ( SELECT b FROM x2 UNION SELECT 123 )
816+
SELECT count(*) FROM x1 WHERE a IN c;
817+
WITH c(x) AS ( SELECT 123 UNION SELECT b FROM x2 )
818+
SELECT count(*) FROM x1 WHERE a IN c;
819+
} {0 0}
820+
do_execsql_test view-31.2 {
821+
CREATE TABLE t3(a INTEGER, b TEXT);
822+
INSERT INTO t3 VALUES(123, 123);
823+
WITH s AS ( VALUES(123), (456) ) SELECT * FROM t3 WHERE b IN s;
824+
} {123 123}
825+
826+
804827
finish_test

0 commit comments

Comments
 (0)