Compare commits
22 Commits
master
...
lateral-jo
Author | SHA1 | Date | |
---|---|---|---|
![]() |
f3d8b19e56 | ||
![]() |
c3c8da56a4 | ||
![]() |
17fb5a8814 | ||
![]() |
86b08d33d4 | ||
![]() |
a40c01987a | ||
![]() |
ddd2d67fdc | ||
![]() |
0f4cf78c2b | ||
![]() |
ce9ef1d43f | ||
![]() |
9b554155d8 | ||
![]() |
d5576fd50b | ||
![]() |
4b94ff8023 | ||
![]() |
a299ed1da6 | ||
![]() |
5fd0f3b777 | ||
![]() |
6937a96b3b | ||
![]() |
bbf444a12c | ||
![]() |
0303047cc6 | ||
![]() |
482b127351 | ||
![]() |
3231316241 | ||
![]() |
aa2e8adcd0 | ||
![]() |
19b62a175f | ||
![]() |
f772da8333 | ||
![]() |
ad674beccf |
35
manifest
35
manifest
@ -1,10 +1,10 @@
|
||||
C Update\sthe\scompile-for-*.md\sdocuments.
|
||||
D 2024-10-25T15:28:00.541
|
||||
C Merge\sthe\slatest\strunk\senhancements\sinto\sthe\slateral-join\sbranch.
|
||||
D 2024-10-25T16:20:21.701
|
||||
F .fossil-settings/empty-dirs dbb81e8fc0401ac46a1491ab34a7f2c7c0452f2f06b54ebb845d024ca8283ef1
|
||||
F .fossil-settings/ignore-glob 35175cdfcf539b2318cb04a9901442804be81cd677d8b889fcc9149c21f239ea
|
||||
F LICENSE.md b6e6c1baf38e4339bd3f1e0e5e5bfd0a9a93d133360691b2785c2d4b2f2dcec2
|
||||
F Makefile.in 5a95c68b70be1448a6f226c09c1df5e338cc496e70987173fcfdca9ad94cb5a4
|
||||
F Makefile.linux-generic 8df0e6ee5e4671f844caf27f88d2be7421e904639f7a0ffdce0e2cd4ea11e8c0
|
||||
F Makefile.linux-generic 8df0e6ee5e4671f844caf27f88d2be7421e904639f7a0ffdce0e2cd4ea11e8c0 w Makefile.linux-gcc
|
||||
F Makefile.msc 28318970f86f601ac79b5e6a514a52fb33a1526d0e0e915b4edc2f41846c1d4a
|
||||
F README.md c3c0f19532ce28f6297a71870f3c7b424729f0e6d9ab889616d3587dd2332159
|
||||
F VERSION 8dc0c3df15fd5ff0622f88fc483533fce990b1cbb2f5fb9fdfb4dbd71eef2889
|
||||
@ -22,7 +22,7 @@ F autoconf/README.first 6c4f34fe115ff55d4e8dbfa3cecf04a0188292f7
|
||||
F autoconf/README.txt 5e946ffb6fbdbb114c81e1bdc862df27fce8beab557d7b0421820b0fe8fc048f
|
||||
F autoconf/configure.ac ec7fa914c5e74ff212fe879f9bb6918e1234497e05facfb641f30c4d5893b277
|
||||
F autoconf/tea/Makefile.in ba0556fee8da09c066bad85a4457904e46ee2c2eabaa309c0e83a78f2f151a8e
|
||||
F autoconf/tea/README.txt 61e62e519579e4a112791354d6d440f8b51ea6db3b0bab58d59f29df42d2dfe3
|
||||
F autoconf/tea/README.txt 61e62e519579e4a112791354d6d440f8b51ea6db3b0bab58d59f29df42d2dfe3 w autoconf/tea/README
|
||||
F autoconf/tea/aclocal.m4 52c47aac44ce0ddb1f918b6993e8beb8eee88f43
|
||||
F autoconf/tea/configure.ac ff2d745f88e493080810b67958d88b4f7a7d79f19e2ee8e7f72ffd6fc04eabc7
|
||||
F autoconf/tea/doc/sqlite3.n e1fe45d4f5286ee3d0ccc877aca2a0def488e9bb
|
||||
@ -729,7 +729,7 @@ F src/btmutex.c 79a43670447eacc651519a429f6ece9fd638563cf95b469d6891185ddae2b522
|
||||
F src/btree.c 63ca6b647342e8cef643863cd0962a542f133e1069460725ba4461dcda92b03c
|
||||
F src/btree.h 18e5e7b2124c23426a283523e5f31a4bff029131b795bb82391f9d2f3136fc50
|
||||
F src/btreeInt.h 98aadb6dcb77b012cab2574d6a728fad56b337fc946839b9898c4b4c969e30b6
|
||||
F src/build.c 3a1840d9d171ce2d24f4c1f7acda7266ab796c664290c1acba65ff98ce2bd01e
|
||||
F src/build.c a6852fb4f545430ba37a5b542c02a12c70a2c146007d0482cf919b6639790017
|
||||
F src/callback.c db3a45e376deff6a16c0058163fe0ae2b73a2945f3f408ca32cf74960b28d490
|
||||
F src/complete.c a3634ab1e687055cd002e11b8f43eb75c17da23e
|
||||
F src/ctime.c b224d3db0f28c4a5f1407c50107a0a8133bd244ff3c7f6f8cedeb896a8cf1b64
|
||||
@ -776,7 +776,7 @@ F src/os_win.c 69fa1aaff68270423c85cff4327ba17ef99a1eb017e1a2bfb97416d9b8398b05
|
||||
F src/os_win.h 7b073010f1451abe501be30d12f6bc599824944a
|
||||
F src/pager.c 9656ad4e8331efb8a4f94f7a0c6440b98caea073950a367ea0c728a53b8e62c9
|
||||
F src/pager.h 4b1140d691860de0be1347474c51fee07d5420bd7f802d38cbab8ea4ab9f538a
|
||||
F src/parse.y a7a8d42eeff01d267444ddb476029b0b1726fb70ae3d77984140f17ad02e2d61
|
||||
F src/parse.y 66f160f94a9d85fc6078e20c8df38960663bf950c2adf40dcb4e5eb284937e7c
|
||||
F src/pcache.c 588cc3c5ccaaadde689ed35ce5c5c891a1f7b1f4d1f56f6cf0143b74d8ee6484
|
||||
F src/pcache.h 1497ce1b823cf00094bb0cf3bac37b345937e6f910890c626b16512316d3abf5
|
||||
F src/pcache1.c 49516ad7718a3626f28f710fa7448ef1fce3c07fd169acbb4817341950264319
|
||||
@ -785,14 +785,14 @@ F src/pragma.h e690a356c18e98414d2e870ea791c1be1545a714ba623719deb63f7f226d8bb7
|
||||
F src/prepare.c 3ba0ad907b7773ed642f66cea8a2c9c8edc18841aa1050b6218dbb3479e86225
|
||||
F src/printf.c 6a87534ebfb9e5346011191b1f3a7ebc457f5938c7e4feeea478ecf53f6a41b2
|
||||
F src/random.c 606b00941a1d7dd09c381d3279a058d771f406c5213c9932bbd93d5587be4b9c
|
||||
F src/resolve.c c8a5372b97b2a2e972a280676f06ddb5b74e885d3b1f5ce383f839907b57ef68
|
||||
F src/resolve.c e3a874206821d97ccad46b320b8eeb16c492d3a95efbf398545bc62610341848
|
||||
F src/rowset.c 8432130e6c344b3401a8874c3cb49fefe6873fec593294de077afea2dce5ec97
|
||||
F src/select.c 4b14337a2742f0c0beeba490e9a05507e9b4b12184b9cd12773501d08d48e3fe
|
||||
F src/select.c 56d01088729122e0fcbdcf3d02371eea64a86e9d7f3668d672e62ea8bd516122
|
||||
F src/shell.c.in 0662f9bcf0725461778d0254a06150e5d61c08c5a87a7281ccdf45552050c79d
|
||||
F src/sqlite.h.in 29fc900a58f394c7488d093fd7a8dcb14d3fa6399d5178cb20adcf88dbedfe39
|
||||
F src/sqlite3.rc 5121c9e10c3964d5755191c80dd1180c122fc3a8
|
||||
F src/sqlite3ext.h 3f046c04ea3595d6bfda99b781926b17e672fd6d27da2ba6d8d8fc39981dcb54
|
||||
F src/sqliteInt.h baae24292817e13e7fe748851c62efc381dcc4dac241b1182eac3d2f05eae52c
|
||||
F src/sqliteInt.h f5633a9579d2889bca146e0b421dcadeb9f5c26c830cbf7d7e886304dc5c90ae
|
||||
F src/sqliteLimit.h 6878ab64bdeb8c24a1d762d45635e34b96da21132179023338c93f820eee6728
|
||||
F src/status.c cb11f8589a6912af2da3bb1ec509a94dd8ef27df4d4c1a97e0bcf2309ece972b
|
||||
F src/table.c 0f141b58a16de7e2fbe81c308379e7279f4c6b50eb08efeec5892794a0ba30d1
|
||||
@ -850,14 +850,14 @@ F src/test_window.c 6d80e11fba89a1796525e6f0048ff0c7789aa2c6b0b11c80827dc1437bd8
|
||||
F src/test_wsd.c 41cadfd9d97fe8e3e4e44f61a4a8ccd6f7ca8fe9
|
||||
F src/threads.c 4ae07fa022a3dc7c5beb373cf744a85d3c5c6c3c
|
||||
F src/tokenize.c 3f703cacdab728d7741e5a6ac242006d74fe1c2754d4f03ed889d7253259bd68
|
||||
F src/treeview.c 88aa39b754f5ef7214385c1bbbdd2f3dc20efafeed0cf590e8d1199b9c6e44aa
|
||||
F src/treeview.c ebcf0398c5a7451b98df58ad9f1097aa959642a394be76d689d135088c310bf6
|
||||
F src/trigger.c 0bb986a5b96047fd597c6aac28588853df56064e576e6b81ba777ef2ccaac461
|
||||
F src/update.c 0e01aa6a3edf9ec112b33eb714b9016a81241497b1fb7c3e74332f4f71756508
|
||||
F src/upsert.c 215328c3f91623c520ec8672c44323553f12caeb4f01b1090ebdca99fdf7b4f1
|
||||
F src/utf.c 8b29d9a5956569ea2700f869669b8ef67a9662ee5e724ff77ab3c387e27094ba
|
||||
F src/util.c ceebf912f673247e305f16f97f0bb7285fca1d37413b79680714a553a9021d33
|
||||
F src/vacuum.c b763b6457bd058d2072ef9364832351fd8d11e8abf70cbb349657360f7d55c40
|
||||
F src/vdbe.c 1f56a0ae24115c2e37213e77cf79aa3b8c8d0366755707385564f6b8dd83d0fb
|
||||
F src/vdbe.c 9ec4afefb7298be2a4d07fcb35796adf56a24d1fa4cede1aa4e43f4a9129d9cb
|
||||
F src/vdbe.h c2549a215898a390de6669cfa32adba56f0d7e17ba5a7f7b14506d6fd5f0c36a
|
||||
F src/vdbeInt.h af7d7e8291edd0b19f2cd698e60e4d4031078f9a2f2328ac8f0b7efb134f8a1d
|
||||
F src/vdbeapi.c 53c7e26a2c0821a892b20eee2cde4656e31998212f3d515576c780dfaa45fd17
|
||||
@ -872,9 +872,9 @@ F src/vxworks.h d2988f4e5a61a4dfe82c6524dd3d6e4f2ce3cdb9
|
||||
F src/wal.c 8b7e309a8012659ac9275ad8cdcc6acaf73fa04b1090e38a01335f230fd10681
|
||||
F src/wal.h ba252daaa94f889f4b2c17c027e823d9be47ce39da1d3799886bbd51f0490452
|
||||
F src/walker.c d5006d6b005e4ea7302ad390957a8d41ed83faa177e412f89bc5600a7462a014
|
||||
F src/where.c 4de9e7ca5f49e4a21c1d733e2b2fbbc8b62b1a157a58a562c569da84cfcb005b
|
||||
F src/where.c 43de02fffdb0ab87926db5bfeb5aed6a67311d9f0190885bf0ca58a95e05a8dc
|
||||
F src/whereInt.h 1e36ec50392f7cc3d93d1152d4338064cd522b87156a0739388b7e273735f0ca
|
||||
F src/wherecode.c 81b9af89f4f85c8097d0da6a31499f015eabc4d3584963d30ba7b7b782e26514
|
||||
F src/wherecode.c bb0a390fd84cbedc09887edeb333c66ce7a0dd5e52972e8a15f67e31277aca01
|
||||
F src/whereexpr.c 0f93a29cabd3a338d09a1f5c6770620a1ac51ec1157f3229502a7e7767c60b6f
|
||||
F src/window.c 499d48f315a09242dc68f2fac635ed27dcf6bbb0d9ab9084857898c64489e975
|
||||
F test/8_3_names.test ebbb5cd36741350040fd28b432ceadf495be25b2
|
||||
@ -1382,6 +1382,7 @@ F test/joinD.test 2ce62e7353a0702ca5e70008faf319c1d4686aa19fba34275c6d1da0e960be
|
||||
F test/joinE.test d5d182f3812771e2c0d97c9dcf5dbe4c41c8e21c82560e59358731c4a3981d6b
|
||||
F test/joinF.test 53dd66158806823ea680dd7543b5406af151b5aafa5cd06a7f3231cd94938127
|
||||
F test/joinH.test 55f69e64da74d4eca2235237f3acb657aef181e22e45daa228e35bba865e0255
|
||||
F test/joinL.test f4c7e70dc2cc293b70d4fbbeab19724366e62d6ebc15eb7005bff6e269d2297e
|
||||
F test/journal1.test c7b768041b7f494471531e17abc2f4f5ebf9e5096984f43ed17c4eb80ba34497
|
||||
F test/journal2.test 9dac6b4ba0ca79c3b21446bbae993a462c2397c4
|
||||
F test/journal3.test 7c3cf23ffc77db06601c1fcfc9743de8441cb77db9d1aa931863d94f5ffa140e
|
||||
@ -2198,7 +2199,7 @@ F tool/spellsift.tcl 52b4b04dc4333c7ab024f09d9d66ed6b6f7c6eb00b38497a09f338fa55d
|
||||
F tool/split-sqlite3c.tcl 5aa60643afca558bc732b1444ae81a522326f91e1dc5665b369c54f09e20de60
|
||||
F tool/sqldiff.c 2a0987d183027c795ced13d6749061c1d2f38e24eddb428f56fa64c3a8f51e4b
|
||||
F tool/sqlite3_analyzer.c.in 348ba349bbdc93c9866439f9f935d7284866a2a4e6898bc906ae1204ade56918
|
||||
F tool/sqlite3_rsync.c 6c9cac5a9197f591985b271aeff803ec4fb4db36c8eab97e1331ff64aa1b8d94
|
||||
F tool/sqlite3_rsync.c 6c9cac5a9197f591985b271aeff803ec4fb4db36c8eab97e1331ff64aa1b8d94 w tool/sqlite3-rsync.c
|
||||
F tool/sqltclsh.c.in 1bcc2e9da58fadf17b0bf6a50e68c1159e602ce057210b655d50bad5aaaef898
|
||||
F tool/sqltclsh.tcl 862f4cf1418df5e1315b5db3b5ebe88969e2a784525af5fbf9596592f14ed848
|
||||
F tool/src-verify.c d00f93263aa2fa6ba0cba0106d95458e6effb94fdb5fc634f56834f90c05bbb4
|
||||
@ -2237,8 +2238,8 @@ F vsixtest/vsixtest.tcl 6195aba1f12a5e10efc2b8c0009532167be5e301abe5b31385638080
|
||||
F vsixtest/vsixtest.vcxproj.data 2ed517e100c66dc455b492e1a33350c1b20fbcdc
|
||||
F vsixtest/vsixtest.vcxproj.filters 37e51ffedcdb064aad6ff33b6148725226cd608e
|
||||
F vsixtest/vsixtest_TemporaryKey.pfx e5b1b036facdb453873e7084e1cae9102ccc67a0
|
||||
P d8c0e0184226bdae9785199d486200e49db7973d78502d09db7a7e34ab0af941
|
||||
R 4d14b0cf75d6af0603108fd77389184c
|
||||
P aafab58453c9581c8608c6ff5800decc6602f77839c592b69666c7fd81ae4e9d c4da7fa279274e5a6fe214b5c22f17bcf9b40299aeeab5bfbdae2ba0b2de6af0
|
||||
R 745e7259b76c587e5e87ccdb51c45a06
|
||||
U drh
|
||||
Z 668ae18c27501de00efe113f6d944d91
|
||||
Z ded64dcb89ad05ac98bc10583f61d154
|
||||
# Remove this line to create a well-formed Fossil manifest.
|
||||
|
@ -1 +1 @@
|
||||
c4da7fa279274e5a6fe214b5c22f17bcf9b40299aeeab5bfbdae2ba0b2de6af0
|
||||
e7f27bbdf4822eb9f145055728fefbf3c4c2080118a7ba194e90d304c0b47da1
|
||||
|
@ -5188,7 +5188,11 @@ void sqlite3SrcListFuncArgs(Parse *pParse, SrcList *p, ExprList *pList){
|
||||
**
|
||||
** The operator is "natural cross join". The A and B operands are stored
|
||||
** in p->a[0] and p->a[1], respectively. The parser initially stores the
|
||||
** operator with A. This routine shifts that operator over to B.
|
||||
** operator with A in p->a[0]. This routine shifts that operator over to
|
||||
** B in p->a[1]. After this shift, the left-most term (p->a[0].fg.jointype)
|
||||
** is not used except as a placeholder for JT_LTORJ and/or JT_LATERAL to
|
||||
** indicate that at least one RIGHT JOIN or LATERAL JOIN (respectively)
|
||||
** occurs somewhere in the FROM.
|
||||
**
|
||||
** Additional changes:
|
||||
**
|
||||
|
26
src/parse.y
26
src/parse.y
@ -735,6 +735,32 @@ seltablist(A) ::= stl_prefix(A) nm(Y) dbnm(D) LP exprlist(E) RP as(Z) on_using(N
|
||||
seltablist(A) ::= stl_prefix(A) LP select(S) RP as(Z) on_using(N). {
|
||||
A = sqlite3SrcListAppendFromTerm(pParse,A,0,0,&Z,S,&N);
|
||||
}
|
||||
seltablist(A) ::= stl_prefix(A) nm(Y) dbnm(D) LP select(S) RP as(Z) on_using(N). {
|
||||
/* \___________/
|
||||
** |
|
||||
** This must be a single identifier token "LATERAL". We cannot make
|
||||
** LATERAL a keyword, since there might be legacy databases that
|
||||
** use "lateral" as a table name and a table name is valid syntax
|
||||
** in this position.
|
||||
*/
|
||||
SrcList *pSrc = A;
|
||||
if( Y.n!=7 || sqlite3StrNICmp(Y.z,"lateral",7)!=0 || D.z!=0 ){
|
||||
sqlite3ErrorMsg(pParse, "near \"%T\": syntax error", &Y);
|
||||
}else
|
||||
if( pSrc
|
||||
&& ALWAYS(pSrc->nSrc>0)
|
||||
&& (pSrc->a[pSrc->nSrc-1].fg.jointype & JT_RIGHT)!=0
|
||||
){
|
||||
sqlite3ErrorMsg(pParse, "join must be INNER or LEFT for a LATERAL reference");
|
||||
pParse->db->errByteOffset = (int)(Y.z - pParse->zTail);
|
||||
}
|
||||
pSrc = A = sqlite3SrcListAppendFromTerm(pParse,A,0,0,&Z,S,&N);
|
||||
if( pParse->nErr==0 && ALWAYS(pSrc!=0) && pSrc->nSrc>1 ){
|
||||
pSrc->a[pSrc->nSrc-1].fg.isLateral = 1;
|
||||
pSrc->a[pSrc->nSrc-2].fg.jointype |= JT_LATERAL;
|
||||
if( ALWAYS(S!=0) ) S->selFlags |= SF_Lateral;
|
||||
}
|
||||
}
|
||||
seltablist(A) ::= stl_prefix(A) LP seltablist(F) RP as(Z) on_using(N). {
|
||||
if( A==0 && Z.n==0 && N.pOn==0 && N.pUsing==0 ){
|
||||
A = F;
|
||||
|
@ -1883,17 +1883,16 @@ static int resolveSelectStep(Walker *pWalker, Select *p){
|
||||
nCompound = 0;
|
||||
pLeftmost = p;
|
||||
while( p ){
|
||||
int nSrc;
|
||||
assert( (p->selFlags & SF_Expanded)!=0 );
|
||||
assert( (p->selFlags & SF_Resolved)==0 );
|
||||
p->selFlags |= SF_Resolved;
|
||||
|
||||
/* Resolve the expressions in the LIMIT and OFFSET clauses. These
|
||||
** are not allowed to refer to any names, so pass an empty NameContext.
|
||||
*/
|
||||
/* Resolve the expressions in the LIMIT and OFFSET clauses. */
|
||||
memset(&sNC, 0, sizeof(sNC));
|
||||
sNC.pParse = pParse;
|
||||
sNC.pWinSelect = p;
|
||||
if( sqlite3ResolveExprNames(&sNC, p->pLimit) ){
|
||||
if( p->pLimit!=0 && sqlite3ResolveExprNames(&sNC, p->pLimit) ){
|
||||
return WRC_Abort;
|
||||
}
|
||||
|
||||
@ -1918,7 +1917,8 @@ static int resolveSelectStep(Walker *pWalker, Select *p){
|
||||
/* Recursively resolve names in all subqueries in the FROM clause
|
||||
*/
|
||||
if( pOuterNC ) pOuterNC->nNestedSelect++;
|
||||
for(i=0; i<p->pSrc->nSrc; i++){
|
||||
nSrc = p->pSrc->nSrc;
|
||||
for(i=0; i<nSrc; i++){
|
||||
SrcItem *pItem = &p->pSrc->a[i];
|
||||
assert( pItem->zName!=0
|
||||
|| pItem->fg.isSubquery ); /* Test of tag-20240424-1*/
|
||||
@ -1926,10 +1926,35 @@ static int resolveSelectStep(Walker *pWalker, Select *p){
|
||||
&& (pItem->u4.pSubq->pSelect->selFlags & SF_Resolved)==0
|
||||
){
|
||||
int nRef = pOuterNC ? pOuterNC->nRef : 0;
|
||||
int nRef2 = sNC.nRef;
|
||||
NameContext *pSubNC;
|
||||
const char *zSavedContext = pParse->zAuthContext;
|
||||
|
||||
if( pItem->zName ) pParse->zAuthContext = pItem->zName;
|
||||
sqlite3ResolveSelectNames(pParse, pItem->u4.pSubq->pSelect, pOuterNC);
|
||||
if( pItem->fg.isLateral ){
|
||||
assert( i>0 ); /* Because p->pSub->a[0] is never marked LATERAL */
|
||||
assert( pItem->u4.pSubq->pSelect!=0 );
|
||||
assert( pItem->u4.pSubq->pSelect->selFlags & SF_Lateral );
|
||||
p->pSrc->nSrc = i;
|
||||
sNC.pSrcList = p->pSrc;
|
||||
if( pItem->u4.pSubq->pSelect->pLimit ){
|
||||
/* If a LIMIT/OFFSET clause exists on a LATERAL subquery, allow
|
||||
** variables from other FROM clause terms to the left of the
|
||||
** subquery to be used in the LIMIT/OFFSET clause. */
|
||||
sNC.pNext = 0;
|
||||
(void)sqlite3ResolveExprNames(&sNC, pItem->u4.pSubq->pSelect->pLimit);
|
||||
}
|
||||
sNC.pNext = pOuterNC;
|
||||
pSubNC = &sNC;
|
||||
}else{
|
||||
sNC.pSrcList = 0;
|
||||
sNC.pNext = 0;
|
||||
pSubNC = pOuterNC;
|
||||
}
|
||||
sqlite3ResolveSelectNames(pParse, pItem->u4.pSubq->pSelect, pSubNC);
|
||||
p->pSrc->nSrc = nSrc;
|
||||
if( sNC.nRef>nRef2 ){
|
||||
pItem->fg.isCorrelated = 1;
|
||||
}
|
||||
pParse->zAuthContext = zSavedContext;
|
||||
if( pParse->nErr ) return WRC_Abort;
|
||||
assert( db->mallocFailed==0 );
|
||||
@ -1940,9 +1965,8 @@ static int resolveSelectStep(Walker *pWalker, Select *p){
|
||||
** but the innermost outer context object, as lookupName() increments
|
||||
** the refcount on all contexts between the current one and the
|
||||
** context containing the column when it resolves a name. */
|
||||
if( pOuterNC ){
|
||||
assert( pItem->fg.isCorrelated==0 && pOuterNC->nRef>=nRef );
|
||||
pItem->fg.isCorrelated = (pOuterNC->nRef>nRef);
|
||||
if( pOuterNC && pOuterNC->nRef>nRef ){
|
||||
pItem->fg.isCorrelated = 1;
|
||||
}
|
||||
}
|
||||
}
|
||||
|
25
src/select.c
25
src/select.c
@ -293,13 +293,12 @@ int sqlite3JoinType(Parse *pParse, Token *pA, Token *pB, Token *pC){
|
||||
}
|
||||
testcase( j==0 || j==1 || j==2 || j==3 || j==4 || j==5 || j==6 );
|
||||
if( j>=ArraySize(aKeyword) ){
|
||||
jointype |= JT_ERROR;
|
||||
jointype = JT_OUTER; /* Triggers error report below */
|
||||
break;
|
||||
}
|
||||
}
|
||||
if(
|
||||
(jointype & (JT_INNER|JT_OUTER))==(JT_INNER|JT_OUTER) ||
|
||||
(jointype & JT_ERROR)!=0 ||
|
||||
(jointype & (JT_OUTER|JT_LEFT|JT_RIGHT))==JT_OUTER
|
||||
){
|
||||
const char *zSp1 = " ";
|
||||
@ -3984,6 +3983,7 @@ static void substSelect(
|
||||
substExprList(pSubst, p->pEList);
|
||||
substExprList(pSubst, p->pGroupBy);
|
||||
substExprList(pSubst, p->pOrderBy);
|
||||
p->pLimit = substExpr(pSubst, p->pLimit);
|
||||
p->pHaving = substExpr(pSubst, p->pHaving);
|
||||
p->pWhere = substExpr(pSubst, p->pWhere);
|
||||
pSrc = p->pSrc;
|
||||
@ -7301,7 +7301,7 @@ static int sameSrcAlias(SrcItem *p0, SrcList *pSrc){
|
||||
** (a) the AS MATERIALIZED keyword is used, or
|
||||
** (b) the CTE is used multiple times and does not have the
|
||||
** NOT MATERIALIZED keyword
|
||||
** (3) The subquery is not part of a left operand for a RIGHT JOIN
|
||||
** (3) The FROM clause does not contain a RIGHT JOIN
|
||||
** (4) The SQLITE_Coroutine optimization disable flag is not set
|
||||
** (5) The subquery is not self-joined
|
||||
*/
|
||||
@ -7330,7 +7330,12 @@ static int fromClauseTermCanBeCoroutine(
|
||||
}
|
||||
if( selFlags & SF_UpdateFrom ) return 0; /* (1c-iii) */
|
||||
while( 1 /*exit-by-break*/ ){
|
||||
if( pItem->fg.jointype & (JT_OUTER|JT_CROSS) ) return 0; /* (1c-ii) */
|
||||
if( pItem->fg.jointype & (JT_OUTER|JT_CROSS|JT_LATERAL) ){
|
||||
testcase( pItem->fg.jointype & JT_OUTER );
|
||||
testcase( pItem->fg.jointype & JT_CROSS );
|
||||
testcase( pItem->fg.jointype & JT_LATERAL );
|
||||
return 0; /* (1c-ii) */
|
||||
}
|
||||
if( i==0 ) break;
|
||||
i--;
|
||||
pItem--;
|
||||
@ -7852,7 +7857,8 @@ int sqlite3Select(
|
||||
*/
|
||||
int addrTop = sqlite3VdbeCurrentAddr(v)+1;
|
||||
|
||||
pSubq->regReturn = ++pParse->nMem;
|
||||
assert( pItem->fg.isLateral==0 );
|
||||
pItem->u4.pSubq->regReturn = ++pParse->nMem;
|
||||
sqlite3VdbeAddOp3(v, OP_InitCoroutine, pSubq->regReturn, 0, addrTop);
|
||||
VdbeComment((v, "%!S", pItem));
|
||||
pSubq->addrFillSub = addrTop;
|
||||
@ -7919,6 +7925,15 @@ int sqlite3Select(
|
||||
ExplainQueryPlan2(addrExplain, (pParse, 1, "MATERIALIZE %!S", pItem));
|
||||
sqlite3Select(pParse, pSub, &dest);
|
||||
pItem->pSTab->nRowLogEst = pSub->nSelectRow;
|
||||
if( pItem->fg.isLateral && pItem->fg.isCorrelated ){
|
||||
int kk;
|
||||
for(kk=0; kk<i; kk++){
|
||||
SrcItem *pX = &pTabList->a[kk];
|
||||
if( pX->fg.viaCoroutine==0 ) continue;
|
||||
sqlite3TranslateColumnToCopy(pParse, topAddr+1,
|
||||
pX->iCursor, pX->u4.pSubq->regResult, 0);
|
||||
}
|
||||
}
|
||||
if( onceAddr ) sqlite3VdbeJumpHere(v, onceAddr);
|
||||
sqlite3VdbeAddOp2(v, OP_Return, pSubq->regReturn, topAddr+1);
|
||||
VdbeComment((v, "end %!S", pItem));
|
||||
|
@ -3289,10 +3289,10 @@ struct Subquery {
|
||||
** The SrcItem object represents a single term in the FROM clause of a query.
|
||||
** The SrcList object is mostly an array of SrcItems.
|
||||
**
|
||||
** The jointype starts out showing the join type between the current table
|
||||
** and the next table on the list. The parser builds the list this way.
|
||||
** The jointype starts out showing the join type between the current term
|
||||
** and the next term on the list. The parser builds the list this way.
|
||||
** But sqlite3SrcListShiftJoinType() later shifts the jointypes so that each
|
||||
** jointype expresses the join between the table and the previous table.
|
||||
** jointype expresses the join between the current term and the previous.
|
||||
**
|
||||
** In the colUsed field, the high-order bit (bit 63) is set if the table
|
||||
** contains more than 63 columns and the 64-th or later column is used.
|
||||
@ -3327,12 +3327,13 @@ struct SrcItem {
|
||||
char *zAlias; /* The "B" part of a "A AS B" phrase. zName is the "A" */
|
||||
Table *pSTab; /* Table object for zName. Mnemonic: Srcitem-TABle */
|
||||
struct {
|
||||
u8 jointype; /* Type of join between this table and the previous */
|
||||
u8 jointype; /* Type of join. See above for more detail. */
|
||||
unsigned notIndexed :1; /* True if there is a NOT INDEXED clause */
|
||||
unsigned isIndexedBy :1; /* True if there is an INDEXED BY clause */
|
||||
unsigned isSubquery :1; /* True if this term is a subquery */
|
||||
unsigned isTabFunc :1; /* True if table-valued-function syntax */
|
||||
unsigned isCorrelated :1; /* True if sub-query is correlated */
|
||||
unsigned isLateral :1; /* True if sub-query is LATERAL */
|
||||
unsigned isMaterialized:1; /* This is a materialized view */
|
||||
unsigned viaCoroutine :1; /* Implemented as a co-routine */
|
||||
unsigned isRecursive :1; /* True for recursive reference in WITH */
|
||||
@ -3402,7 +3403,9 @@ struct SrcList {
|
||||
#define JT_OUTER 0x20 /* The "OUTER" keyword is present */
|
||||
#define JT_LTORJ 0x40 /* One of the LEFT operands of a RIGHT JOIN
|
||||
** Mnemonic: Left Table Of Right Join */
|
||||
#define JT_ERROR 0x80 /* unknown or unsupported join type */
|
||||
#define JT_LATERAL 0x80 /* A LATERAL join. Or, if on the left-most
|
||||
** SrcItem, an indication that at least one
|
||||
** correlated LATERAL join exists in the FROM */
|
||||
|
||||
/*
|
||||
** Flags appropriate for the wctrlFlags parameter of sqlite3WhereBegin()
|
||||
@ -3610,7 +3613,7 @@ struct Select {
|
||||
#define SF_MinMaxAgg 0x0001000 /* Aggregate containing min() or max() */
|
||||
#define SF_Recursive 0x0002000 /* The recursive part of a recursive CTE */
|
||||
#define SF_FixedLimit 0x0004000 /* nSelectRow set by a constant LIMIT */
|
||||
#define SF_MaybeConvert 0x0008000 /* Need convertCompoundSelectToSubquery() */
|
||||
#define SF_Lateral 0x0008000 /* Is of the form: LATERAL(SELECT ...) */
|
||||
#define SF_Converted 0x0010000 /* By convertCompoundSelectToSubquery() */
|
||||
#define SF_IncludeHidden 0x0020000 /* Include hidden columns in output */
|
||||
#define SF_ComplexResult 0x0040000 /* Result contains subquery or function */
|
||||
@ -5046,6 +5049,13 @@ void sqlite3Update(Parse*, SrcList*, ExprList*,Expr*,int,ExprList*,Expr*,
|
||||
WhereInfo *sqlite3WhereBegin(Parse*,SrcList*,Expr*,ExprList*,
|
||||
ExprList*,Select*,u16,int);
|
||||
void sqlite3WhereEnd(WhereInfo*);
|
||||
void sqlite3TranslateColumnToCopy(
|
||||
Parse *pParse, /* Parsing context */
|
||||
int iStart, /* Translate from this opcode to the end */
|
||||
int iTabCur, /* OP_Column/OP_Rowid references to this table */
|
||||
int iRegister, /* The first column is in this register */
|
||||
int iAutoidxCur /* If non-zero, cursor of autoindex being generated */
|
||||
);
|
||||
LogEst sqlite3WhereOutputRowCount(WhereInfo*);
|
||||
int sqlite3WhereIsDistinct(WhereInfo*);
|
||||
int sqlite3WhereIsOrdered(WhereInfo*);
|
||||
|
@ -211,6 +211,9 @@ void sqlite3TreeViewSrcList(TreeView *pView, const SrcList *pSrc){
|
||||
if( pItem->fg.jointype & JT_LTORJ ){
|
||||
sqlite3_str_appendf(&x, " LTORJ");
|
||||
}
|
||||
if( pItem->fg.isLateral ){
|
||||
sqlite3_str_appendf(&x, " LATERAL");
|
||||
}
|
||||
if( pItem->fg.fromDDL ){
|
||||
sqlite3_str_appendf(&x, " DDL");
|
||||
}
|
||||
|
@ -2078,6 +2078,9 @@ case OP_MustBeInt: { /* jump0, in1 */
|
||||
}
|
||||
}
|
||||
}
|
||||
#ifdef SQLITE_DEBUG
|
||||
pIn1->pScopyFrom = 0;
|
||||
#endif
|
||||
VdbeBranchTaken(0, 2);
|
||||
MemSetTypeFlag(pIn1, MEM_Int);
|
||||
break;
|
||||
|
54
src/where.c
54
src/where.c
@ -708,7 +708,7 @@ static LogEst estLog(LogEst N){
|
||||
** iAutoidxCur cursor, in order to generate unique rowids for the
|
||||
** automatic index being generated.
|
||||
*/
|
||||
static void translateColumnToCopy(
|
||||
void sqlite3TranslateColumnToCopy(
|
||||
Parse *pParse, /* Parsing context */
|
||||
int iStart, /* Translate from this opcode to the end */
|
||||
int iTabCur, /* OP_Column/OP_Rowid references to this table */
|
||||
@ -1197,8 +1197,8 @@ static SQLITE_NOINLINE void constructAutomaticIndex(
|
||||
sqlite3VdbeChangeP2(v, addrCounter, regBase+n);
|
||||
testcase( pParse->db->mallocFailed );
|
||||
assert( pLevel->iIdxCur>0 );
|
||||
translateColumnToCopy(pParse, addrTop, pLevel->iTabCur,
|
||||
pSrc->u4.pSubq->regResult, pLevel->iIdxCur);
|
||||
sqlite3TranslateColumnToCopy(pParse, addrTop, pLevel->iTabCur,
|
||||
pSrc->u4.pSubq->regResult, pLevel->iIdxCur);
|
||||
sqlite3VdbeGoto(v, addrTop);
|
||||
pSrc->fg.viaCoroutine = 0;
|
||||
}else{
|
||||
@ -4806,12 +4806,13 @@ static int whereLoopAddAll(WhereLoopBuilder *pBuilder){
|
||||
pBuilder->iPlanLimit += SQLITE_QUERY_PLANNER_LIMIT_INCR;
|
||||
pNew->maskSelf = sqlite3WhereGetMask(&pWInfo->sMaskSet, pItem->iCursor);
|
||||
if( bFirstPastRJ
|
||||
|| (pItem->fg.jointype & (JT_OUTER|JT_CROSS|JT_LTORJ))!=0
|
||||
|| (pItem->fg.jointype & (JT_OUTER|JT_CROSS|JT_LTORJ|JT_LATERAL))!=0
|
||||
){
|
||||
/* Add prerequisites to prevent reordering of FROM clause terms
|
||||
** across CROSS joins and outer joins. The bFirstPastRJ boolean
|
||||
** prevents the right operand of a RIGHT JOIN from being swapped with
|
||||
** other elements even further to the right.
|
||||
** across CROSS joins, outer joins, and lateral joins.
|
||||
** The bFirstPastRJ boolean prevents the right operand of a
|
||||
** RIGHT JOIN from being swapped with other elements even further
|
||||
** to the right.
|
||||
**
|
||||
** The JT_LTORJ case and the hasRightJoin flag work together to
|
||||
** prevent FROM-clause terms from moving from the right side of
|
||||
@ -4819,6 +4820,9 @@ static int whereLoopAddAll(WhereLoopBuilder *pBuilder){
|
||||
** is itself on the left side of a RIGHT JOIN.
|
||||
*/
|
||||
if( pItem->fg.jointype & JT_LTORJ ) hasRightJoin = 1;
|
||||
testcase( pItem->fg.jointype & JT_CROSS );
|
||||
testcase( pItem->fg.jointype & JT_OUTER );
|
||||
testcase( pItem->fg.jointype & JT_LATERAL );
|
||||
mPrereq |= mPrior;
|
||||
bFirstPastRJ = (pItem->fg.jointype & JT_RIGHT)!=0;
|
||||
}else if( !hasRightJoin ){
|
||||
@ -4828,7 +4832,10 @@ static int whereLoopAddAll(WhereLoopBuilder *pBuilder){
|
||||
if( IsVirtual(pItem->pSTab) ){
|
||||
SrcItem *p;
|
||||
for(p=&pItem[1]; p<pEnd; p++){
|
||||
if( mUnusable || (p->fg.jointype & (JT_OUTER|JT_CROSS)) ){
|
||||
if( mUnusable || (p->fg.jointype & (JT_OUTER|JT_CROSS|JT_LATERAL)) ){
|
||||
testcase( p->fg.jointype & JT_CROSS );
|
||||
testcase( p->fg.jointype & JT_OUTER );
|
||||
testcase( p->fg.jointype & JT_LATERAL );
|
||||
mUnusable |= sqlite3WhereGetMask(&pWInfo->sMaskSet, p->iCursor);
|
||||
}
|
||||
}
|
||||
@ -6385,6 +6392,30 @@ static SQLITE_NOINLINE void whereReverseScanOrder(WhereInfo *pWInfo){
|
||||
}
|
||||
}
|
||||
|
||||
/*
|
||||
** Adjust the addrBody of all WHERE_IDX_ONLY WhereLoops prior to ii
|
||||
** so that the addrBody covers the subroutine that computes a LATERAL
|
||||
** subquery.
|
||||
**
|
||||
** This routine is broken out into a separate no-inline subroutine because
|
||||
** it runs rarely, and by breaking it out it reduces register contention
|
||||
** in the main sqlite3WhereBegin() routine, helping sqlite3WhereBegin()
|
||||
** to run faster.
|
||||
*/
|
||||
static SQLITE_NOINLINE void whereAdjustAddrBodyForLateral(
|
||||
WhereInfo *pWInfo, /* There WHERE loop info */
|
||||
SrcItem *pSrc, /* The LATERAL subquery */
|
||||
int ii /* Index of pSrc in the FROM clause */
|
||||
){
|
||||
while( --ii >= 0 ){
|
||||
if( pWInfo->a[ii].pWLoop->wsFlags & WHERE_IDX_ONLY
|
||||
&& pWInfo->a[ii].addrBody > pSrc->u4.pSubq->addrFillSub
|
||||
){
|
||||
pWInfo->a[ii].addrBody = pSrc->u4.pSubq->addrFillSub;
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
/*
|
||||
** Generate the beginning of the loop used for WHERE clause processing.
|
||||
** The return value is a pointer to an opaque structure that contains
|
||||
@ -7079,6 +7110,9 @@ WhereInfo *sqlite3WhereBegin(
|
||||
iOnce = sqlite3VdbeAddOp0(v, OP_Once); VdbeCoverage(v);
|
||||
}else{
|
||||
iOnce = 0;
|
||||
if( pSrc->fg.isLateral ){
|
||||
whereAdjustAddrBodyForLateral(pWInfo, pSrc, ii);
|
||||
}
|
||||
}
|
||||
sqlite3VdbeAddOp2(v, OP_Gosub, pSubq->regReturn, pSubq->addrFillSub);
|
||||
VdbeComment((v, "materialize %!S", pSrc));
|
||||
@ -7352,8 +7386,8 @@ void sqlite3WhereEnd(WhereInfo *pWInfo){
|
||||
testcase( pParse->db->mallocFailed );
|
||||
assert( pTabItem->fg.isSubquery );
|
||||
assert( pTabItem->u4.pSubq->regResult>=0 );
|
||||
translateColumnToCopy(pParse, pLevel->addrBody, pLevel->iTabCur,
|
||||
pTabItem->u4.pSubq->regResult, 0);
|
||||
sqlite3TranslateColumnToCopy(pParse, pLevel->addrBody, pLevel->iTabCur,
|
||||
pTabItem->u4.pSubq->regResult, 0);
|
||||
continue;
|
||||
}
|
||||
|
||||
|
@ -1462,6 +1462,32 @@ static int whereLoopIsOneRow(WhereLoop *pLoop){
|
||||
return 0;
|
||||
}
|
||||
|
||||
/*
|
||||
** Find an appropriate label for iLevel loop to jump to if it the table
|
||||
** for that loop is empty.
|
||||
**
|
||||
** For a simple query, we might as well jump to the break-address of the
|
||||
** outermost loop, halting the query, since if one of the joined tables
|
||||
** is empty, the result set will be empty. But that does not work if
|
||||
** there are outer joins. Nor does it work if the empty table is a
|
||||
** correlated subquery (with the LATERAL keyword).
|
||||
*/
|
||||
static SQLITE_NOINLINE int haltAddress(
|
||||
WhereInfo *pWInfo,
|
||||
int iLevel,
|
||||
SrcItem *pTabItem
|
||||
){
|
||||
if( pTabItem->fg.isLateral==0 || pTabItem->fg.isCorrelated==0 ){
|
||||
while( 1 /*exit-by-break*/ ){
|
||||
if( pWInfo->a[iLevel].iLeftJoin ) break;
|
||||
if( pWInfo->a[iLevel].pRJ ) break;
|
||||
if( iLevel==0 ) break;
|
||||
iLevel--;
|
||||
};
|
||||
}
|
||||
return pWInfo->a[iLevel].addrBrk;
|
||||
}
|
||||
|
||||
/*
|
||||
** Generate code for the start of the iLevel-th loop in the WHERE clause
|
||||
** implementation described by pWInfo.
|
||||
@ -1484,7 +1510,6 @@ Bitmask sqlite3WhereCodeOneLoopStart(
|
||||
sqlite3 *db; /* Database connection */
|
||||
SrcItem *pTabItem; /* FROM clause term being coded */
|
||||
int addrBrk; /* Jump here to break out of the loop */
|
||||
int addrHalt; /* addrBrk for the outermost loop */
|
||||
int addrCont; /* Jump here to continue with next cycle */
|
||||
int iRowidReg = 0; /* Rowid is stored in this register, if not zero */
|
||||
int iReleaseReg = 0; /* Temp register to free before returning */
|
||||
@ -1544,14 +1569,6 @@ Bitmask sqlite3WhereCodeOneLoopStart(
|
||||
VdbeComment((v, "init LEFT JOIN match flag"));
|
||||
}
|
||||
|
||||
/* Compute a safe address to jump to if we discover that the table for
|
||||
** this loop is empty and can never contribute content. */
|
||||
for(j=iLevel; j>0; j--){
|
||||
if( pWInfo->a[j].iLeftJoin ) break;
|
||||
if( pWInfo->a[j].pRJ ) break;
|
||||
}
|
||||
addrHalt = pWInfo->a[j].addrBrk;
|
||||
|
||||
/* Special case of a FROM clause subquery implemented as a co-routine */
|
||||
if( pTabItem->fg.viaCoroutine ){
|
||||
int regYield;
|
||||
@ -1787,7 +1804,8 @@ Bitmask sqlite3WhereCodeOneLoopStart(
|
||||
VdbeCoverageIf(v, pX->op==TK_GE);
|
||||
sqlite3ReleaseTempReg(pParse, rTemp);
|
||||
}else{
|
||||
sqlite3VdbeAddOp2(v, bRev ? OP_Last : OP_Rewind, iCur, addrHalt);
|
||||
sqlite3VdbeAddOp2(v, bRev ? OP_Last : OP_Rewind, iCur,
|
||||
haltAddress(pWInfo, iLevel, pTabItem));
|
||||
VdbeCoverageIf(v, bRev==0);
|
||||
VdbeCoverageIf(v, bRev!=0);
|
||||
}
|
||||
@ -2582,7 +2600,8 @@ Bitmask sqlite3WhereCodeOneLoopStart(
|
||||
codeCursorHint(pTabItem, pWInfo, pLevel, 0);
|
||||
pLevel->op = aStep[bRev];
|
||||
pLevel->p1 = iCur;
|
||||
pLevel->p2 = 1 + sqlite3VdbeAddOp2(v, aStart[bRev], iCur, addrHalt);
|
||||
pLevel->p2 = 1 + sqlite3VdbeAddOp2(v, aStart[bRev], iCur,
|
||||
haltAddress(pWInfo, iLevel, pTabItem));
|
||||
VdbeCoverageIf(v, bRev==0);
|
||||
VdbeCoverageIf(v, bRev!=0);
|
||||
pLevel->p5 = SQLITE_STMTSTATUS_FULLSCAN_STEP;
|
||||
|
235
test/joinL.test
Normal file
235
test/joinL.test
Normal file
@ -0,0 +1,235 @@
|
||||
# 2024-07-20
|
||||
#
|
||||
# The author disclaims copyright to this source code. In place of
|
||||
# a legal notice, here is a blessing:
|
||||
#
|
||||
# May you do good and not evil.
|
||||
# May you find forgiveness for yourself and forgive others.
|
||||
# May you share freely, never taking more than you give.
|
||||
#
|
||||
#***********************************************************************
|
||||
#
|
||||
# Tests for LATERAL JOIN
|
||||
#
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
set testprefix joinL
|
||||
|
||||
db null NULL
|
||||
do_execsql_test 1.0 {
|
||||
CREATE TABLE product(product_id INT, price REAL, product TEXT);
|
||||
INSERT INTO product VALUES
|
||||
(1, 6.76, 'apple'),
|
||||
(2, 5.28, 'banana'),
|
||||
(3, 28.28, 'cherry'),
|
||||
(4, 13.54, 'dates'),
|
||||
(5, 30.58, 'elderberry'),
|
||||
(6, 26.57, 'figs'),
|
||||
(7, 64.85, 'grapes'),
|
||||
(8, 21.55, 'huckleberry'),
|
||||
(9, 29.00, 'jakefruit'),
|
||||
(10, 17.31, 'kiwi');
|
||||
CREATE TABLE wishlist(wishlist_id int, username text, desired_price real);
|
||||
INSERT INTO wishlist VALUES
|
||||
(1, 'alice', 45.0),
|
||||
(2, 'bob', 30.0),
|
||||
(3, 'cindy', 15.0),
|
||||
(4, 'david', 4.0);
|
||||
SELECT *
|
||||
FROM wishlist AS w LEFT JOIN LATERAL (
|
||||
SELECT * FROM product AS p
|
||||
WHERE p.price < w.desired_price
|
||||
ORDER BY p.price DESC LIMIT 3
|
||||
) AS x
|
||||
ORDER BY wishlist_id, price DESC;
|
||||
} {
|
||||
1 alice 45.0 5 30.58 elderberry
|
||||
1 alice 45.0 9 29.0 jakefruit
|
||||
1 alice 45.0 3 28.28 cherry
|
||||
2 bob 30.0 9 29.0 jakefruit
|
||||
2 bob 30.0 3 28.28 cherry
|
||||
2 bob 30.0 6 26.57 figs
|
||||
3 cindy 15.0 4 13.54 dates
|
||||
3 cindy 15.0 1 6.76 apple
|
||||
3 cindy 15.0 2 5.28 banana
|
||||
4 david 4.0 NULL NULL NULL
|
||||
}
|
||||
do_execsql_test 1.1 {
|
||||
SELECT *
|
||||
FROM wishlist AS w JOIN LATERAL (
|
||||
SELECT * FROM product AS p
|
||||
WHERE p.price < w.desired_price
|
||||
ORDER BY p.price DESC LIMIT 3
|
||||
) AS x
|
||||
ORDER BY wishlist_id, price DESC;
|
||||
} {
|
||||
1 alice 45.0 5 30.58 elderberry
|
||||
1 alice 45.0 9 29.0 jakefruit
|
||||
1 alice 45.0 3 28.28 cherry
|
||||
2 bob 30.0 9 29.0 jakefruit
|
||||
2 bob 30.0 3 28.28 cherry
|
||||
2 bob 30.0 6 26.57 figs
|
||||
3 cindy 15.0 4 13.54 dates
|
||||
3 cindy 15.0 1 6.76 apple
|
||||
3 cindy 15.0 2 5.28 banana
|
||||
}
|
||||
|
||||
|
||||
do_catchsql_test 1.2 {
|
||||
SELECT *
|
||||
FROM wishlist AS w RIGHT JOIN LATERAL (
|
||||
SELECT * FROM product AS p
|
||||
WHERE p.price < w.desired_price
|
||||
ORDER BY p.price DESC LIMIT 3
|
||||
) AS x ON true
|
||||
ORDER BY wishlist_id, price DESC;
|
||||
} {1 {join must be INNER or LEFT for a LATERAL reference}}
|
||||
do_catchsql_test 1.3 {
|
||||
SELECT *
|
||||
FROM wishlist AS w FULL OUTER JOIN LATERAL (
|
||||
SELECT * FROM product AS p
|
||||
WHERE p.price < w.desired_price
|
||||
ORDER BY p.price DESC LIMIT 3
|
||||
) AS x ON true
|
||||
ORDER BY wishlist_id, price DESC;
|
||||
} {1 {join must be INNER or LEFT for a LATERAL reference}}
|
||||
do_catchsql_test 1.4 {
|
||||
SELECT *
|
||||
FROM wishlist AS w FULL OUTER JOIN LATERALx (
|
||||
SELECT * FROM product AS p
|
||||
WHERE p.price < w.desired_price
|
||||
ORDER BY p.price DESC LIMIT 3
|
||||
) AS x ON true
|
||||
ORDER BY wishlist_id, price DESC;
|
||||
} {1 {near "LATERALx": syntax error}}
|
||||
do_catchsql_test 1.5 {
|
||||
SELECT *
|
||||
FROM wishlist AS w FULL OUTER JOIN LATERAL.xyz (
|
||||
SELECT * FROM product AS p
|
||||
WHERE p.price < w.desired_price
|
||||
ORDER BY p.price DESC LIMIT 3
|
||||
) AS x ON true
|
||||
ORDER BY wishlist_id, price DESC;
|
||||
} {1 {near "LATERAL": syntax error}}
|
||||
|
||||
do_execsql_test 2.0 {
|
||||
CREATE TABLE orders(id INTEGER PRIMARY KEY, user_id INT, created_at TEXT);
|
||||
INSERT INTO orders VALUES
|
||||
(1,1,'2024-07-20T01:35:03'),
|
||||
(2,2,'2024-07-20T01:35:07'),
|
||||
(3,3,'2024-07-20T01:35:10'),
|
||||
(4,1,'2024-07-20T01:58:10'),
|
||||
(5,3,'2024-07-20T01:58:17'),
|
||||
(6,3,'2024-07-20T01:58:25');
|
||||
|
||||
SELECT user_id, first_order_time, next_order_time, id FROM
|
||||
(SELECT user_id, min(created_at) AS first_order_time
|
||||
FROM orders GROUP BY user_id) AS o1
|
||||
LEFT JOIN LATERAL
|
||||
(SELECT id, created_at AS next_order_time
|
||||
FROM orders
|
||||
WHERE user_id = o1.user_id AND created_at > o1.first_order_time
|
||||
ORDER BY created_at ASC LIMIT 1) AS o2
|
||||
ON true;
|
||||
} {
|
||||
1 2024-07-20T01:35:03 2024-07-20T01:58:10 4
|
||||
2 2024-07-20T01:35:07 NULL NULL
|
||||
3 2024-07-20T01:35:10 2024-07-20T01:58:17 5
|
||||
}
|
||||
do_execsql_test 2.1 {
|
||||
SELECT user_id, first_order_time, next_order_time, id FROM
|
||||
LATERAL (SELECT user_id, min(created_at) AS first_order_time
|
||||
FROM orders GROUP BY user_id) AS o1
|
||||
JOIN LATERAL
|
||||
(SELECT id, created_at AS next_order_time
|
||||
FROM orders
|
||||
WHERE user_id = o1.user_id AND created_at > o1.first_order_time
|
||||
ORDER BY created_at ASC LIMIT 1) AS o2
|
||||
ON true;
|
||||
} {
|
||||
1 2024-07-20T01:35:03 2024-07-20T01:58:10 4
|
||||
3 2024-07-20T01:35:10 2024-07-20T01:58:17 5
|
||||
}
|
||||
|
||||
# "LATERAL" is a not actually a keyword. It can be used as an indentifier for
|
||||
# historical compatibility.
|
||||
#
|
||||
do_execsql_test 3.0 {
|
||||
CREATE TABLE lateral(a,lateral lateral);
|
||||
INSERT INTO lateral VALUES(1,2);
|
||||
SELECT * FROM lateral;
|
||||
ATTACH ':memory:' AS lateral;
|
||||
CREATE TABLE lateral.t2(x,y);
|
||||
INSERT INTO t2 VALUES(98,99);
|
||||
SELECT * FROM t2;
|
||||
} {1 2 98 99}
|
||||
|
||||
# https://sqlite.org/forum/forumpost/dfe2cd37ca3a9a80
|
||||
#
|
||||
do_execsql_test 4.0 {
|
||||
SELECT * FROM (VALUES (1), (2)) JOIN LATERAL (select COUNT(*), column1);
|
||||
} {1 1 1 2 1 2}
|
||||
do_execsql_test 4.1 {
|
||||
CREATE TABLE t3(x INTEGER PRIMARY KEY);
|
||||
WITH RECURSIVE c(n) AS (VALUES(0) UNION ALL SELECT n+1 FROM c WHERE n<20)
|
||||
INSERT INTO t3(x) SELECT n FROM c;
|
||||
CREATE TABLE t4(y,z);
|
||||
INSERT INTO t4 VALUES(1,0),(3,2),(5,7);
|
||||
SELECT * FROM t4, LATERAL(SELECT x FROM t3 ORDER BY x LIMIT y OFFSET z);
|
||||
} {
|
||||
1 0 0
|
||||
3 2 2
|
||||
3 2 3
|
||||
3 2 4
|
||||
5 7 7
|
||||
5 7 8
|
||||
5 7 9
|
||||
5 7 10
|
||||
5 7 11
|
||||
}
|
||||
do_execsql_test 4.2 {
|
||||
SELECT * FROM (VALUES(1,0),(3,2),(5,7)),
|
||||
LATERAL(SELECT x FROM t3 ORDER BY x LIMIT column1 OFFSET column2);
|
||||
} {
|
||||
1 0 0
|
||||
3 2 2
|
||||
3 2 3
|
||||
3 2 4
|
||||
5 7 7
|
||||
5 7 8
|
||||
5 7 9
|
||||
5 7 10
|
||||
5 7 11
|
||||
}
|
||||
|
||||
|
||||
# https://sqlite.org/forum/forumpost/fc29fa4f14
|
||||
#
|
||||
do_execsql_test 5.0 {
|
||||
CREATE TABLE t1(a,b); INSERT INTO t1 VALUES(1,2);
|
||||
CREATE TABLE t2(c,d,e,f); INSERT INTO t2 VALUES(3,4,5,6);
|
||||
CREATE INDEX t2cd ON t2(c,d);
|
||||
CREATE TABLE dual(dummy TEXT); INSERT INTO dual VALUES('X');
|
||||
SELECT c, a, sb
|
||||
FROM t2, LATERAL(
|
||||
SELECT a, sum(b) AS sb FROM t1 GROUP BY a HAVING sum(b)<d
|
||||
) AS lx
|
||||
ORDER BY a, c;
|
||||
} {3 1 2}
|
||||
do_execsql_test 5.1 {
|
||||
SELECT c, a, sb
|
||||
FROM dual, t2, LATERAL(
|
||||
SELECT a, sum(b) AS sb FROM t1 GROUP BY a HAVING sum(b)<d
|
||||
) AS lx
|
||||
ORDER BY a, c;
|
||||
} {3 1 2}
|
||||
do_execsql_test 5.2 {
|
||||
SELECT c, a, sb
|
||||
FROM t2, dual, LATERAL(
|
||||
SELECT a, sum(b) AS sb FROM t1 GROUP BY a HAVING sum(b)<d
|
||||
) AS lx
|
||||
ORDER BY a, c;
|
||||
} {3 1 2}
|
||||
|
||||
finish_test
|
Loading…
x
Reference in New Issue
Block a user