Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | The USING clause and NATURAL JOIN look at all tables to the left when searching for a match, not just the one table to the immediate left. Tables further to the left are preferred. Fix for ticket [f74beaabde]. Still need to add test cases to complete the ticket. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA1: |
b558e96f0a3cd2cbbe86e44293246a47 |
User & Date: | drh 2009-12-09 17:36:40.000 |
References
2009-12-09
| ||
18:23 | • Fixed ticket [f74beaabde]: Problem with 3-way joins and the USING clause plus 2 other changes (artifact: 04c1a6e96a user: drh) | |
Context
2009-12-09
| ||
18:22 | Added test cases for the multi-way USING and NATURAL JOIN fix. Ticket [f74beaabde]. (check-in: 0b34ab2562 user: drh tags: trunk) | |
17:36 | The USING clause and NATURAL JOIN look at all tables to the left when searching for a match, not just the one table to the immediate left. Tables further to the left are preferred. Fix for ticket [f74beaabde]. Still need to add test cases to complete the ticket. (check-in: b558e96f0a user: drh tags: trunk) | |
14:39 | Improve test coverage of fts3.c. (check-in: 56b6432f86 user: dan tags: trunk) | |
Changes
Changes to src/select.c.
︙ | ︙ | |||
184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 | static int columnIndex(Table *pTab, const char *zCol){ int i; for(i=0; i<pTab->nCol; i++){ if( sqlite3StrICmp(pTab->aCol[i].zName, zCol)==0 ) return i; } return -1; } /* ** This function is used to add terms implied by JOIN syntax to the ** WHERE clause expression of a SELECT statement. The new term, which ** is ANDed with the existing WHERE clause, is of the form: ** ** (tab1.col1 = tab2.col2) ** ** where tab1 is the iSrc'th table in SrcList pSrc and tab2 is the ** (iSrc+1)'th. Column col1 is column iColLeft of tab1, and col2 is ** column iColRight of tab2. */ static void addWhereTerm( Parse *pParse, /* Parsing context */ SrcList *pSrc, /* List of tables in FROM clause */ | > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | > > | | | | | | 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 | static int columnIndex(Table *pTab, const char *zCol){ int i; for(i=0; i<pTab->nCol; i++){ if( sqlite3StrICmp(pTab->aCol[i].zName, zCol)==0 ) return i; } return -1; } /* ** Search the first N tables in pSrc, from left to right, looking for a ** table that has a column named zCol. ** ** When found, set *piTab and *piCol to the table index and column index ** of the matching column and return TRUE. ** ** If not found, return FALSE. */ static int tableAndColumnIndex( SrcList *pSrc, /* Array of tables to search */ int N, /* Number of tables in pSrc->a[] to search */ const char *zCol, /* Name of the column we are looking for */ int *piTab, /* Write index of pSrc->a[] here */ int *piCol /* Write index of pSrc->a[*piTab].pTab->aCol[] here */ ){ int i; /* For looping over tables in pSrc */ int iCol; /* Index of column matching zCol */ assert( (piTab==0)==(piCol==0) ); /* Both or neither are NULL */ for(i=0; i<N; i++){ iCol = columnIndex(pSrc->a[i].pTab, zCol); if( iCol>=0 ){ if( piTab ){ *piTab = i; *piCol = iCol; } return 1; } } return 0; } /* ** This function is used to add terms implied by JOIN syntax to the ** WHERE clause expression of a SELECT statement. The new term, which ** is ANDed with the existing WHERE clause, is of the form: ** ** (tab1.col1 = tab2.col2) ** ** where tab1 is the iSrc'th table in SrcList pSrc and tab2 is the ** (iSrc+1)'th. Column col1 is column iColLeft of tab1, and col2 is ** column iColRight of tab2. */ static void addWhereTerm( Parse *pParse, /* Parsing context */ SrcList *pSrc, /* List of tables in FROM clause */ int iLeft, /* Index of first table to join in pSrc */ int iColLeft, /* Index of column in first table */ int iRight, /* Index of second table in pSrc */ int iColRight, /* Index of column in second table */ int isOuterJoin, /* True if this is an OUTER join */ Expr **ppWhere /* IN/OUT: The WHERE clause to add to */ ){ sqlite3 *db = pParse->db; Expr *pE1; Expr *pE2; Expr *pEq; assert( iLeft<iRight ); assert( pSrc->nSrc>iRight ); assert( pSrc->a[iLeft].pTab ); assert( pSrc->a[iRight].pTab ); pE1 = sqlite3CreateColumnExpr(db, pSrc, iLeft, iColLeft); pE2 = sqlite3CreateColumnExpr(db, pSrc, iRight, iColRight); pEq = sqlite3PExpr(pParse, TK_EQ, pE1, pE2, 0); if( pEq && isOuterJoin ){ ExprSetProperty(pEq, EP_FromJoin); assert( !ExprHasAnyProperty(pEq, EP_TokenOnly|EP_Reduced) ); ExprSetIrreducible(pEq); pEq->iRightJoinTable = (i16)pE2->iTable; |
︙ | ︙ | |||
304 305 306 307 308 309 310 | */ if( pRight->jointype & JT_NATURAL ){ if( pRight->pOn || pRight->pUsing ){ sqlite3ErrorMsg(pParse, "a NATURAL join may not have " "an ON or USING clause", 0); return 1; } | | > > > > | | < | > | 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 | */ if( pRight->jointype & JT_NATURAL ){ if( pRight->pOn || pRight->pUsing ){ sqlite3ErrorMsg(pParse, "a NATURAL join may not have " "an ON or USING clause", 0); return 1; } for(j=0; j<pRightTab->nCol; j++){ char *zName; /* Name of column in the right table */ int iLeft; /* Matching left table */ int iLeftCol; /* Matching column in the left table */ zName = pRightTab->aCol[j].zName; if( tableAndColumnIndex(pSrc, i+1, zName, &iLeft, &iLeftCol) ){ addWhereTerm(pParse, pSrc, iLeft, iLeftCol, i+1, j, isOuter, &p->pWhere); } } } /* Disallow both ON and USING clauses in the same join */ if( pRight->pOn && pRight->pUsing ){ |
︙ | ︙ | |||
340 341 342 343 344 345 346 | ** to the WHERE clause: A.X=B.X AND A.Y=B.Y AND A.Z=B.Z ** Report an error if any column mentioned in the USING clause is ** not contained in both tables to be joined. */ if( pRight->pUsing ){ IdList *pList = pRight->pUsing; for(j=0; j<pList->nId; j++){ | > > > > > | < | | > > > | | 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 | ** to the WHERE clause: A.X=B.X AND A.Y=B.Y AND A.Z=B.Z ** Report an error if any column mentioned in the USING clause is ** not contained in both tables to be joined. */ if( pRight->pUsing ){ IdList *pList = pRight->pUsing; for(j=0; j<pList->nId; j++){ char *zName; /* Name of the term in the USING clause */ int iLeft; /* Table on the left with matching column name */ int iLeftCol; /* Column number of matching column on the left */ int iRightCol; /* Column number of matching column on the right */ zName = pList->a[j].zName; iRightCol = columnIndex(pRightTab, zName); if( iRightCol<0 || !tableAndColumnIndex(pSrc, i+1, zName, &iLeft, &iLeftCol) ){ sqlite3ErrorMsg(pParse, "cannot join using column %s - column " "not present in both tables", zName); return 1; } addWhereTerm(pParse, pSrc, iLeft, iLeftCol, i+1, iRightCol, isOuter, &p->pWhere); } } } return 0; } /* |
︙ | ︙ | |||
3165 3166 3167 3168 3169 3170 3171 | */ if( IsHiddenColumn(&pTab->aCol[j]) ){ assert(IsVirtual(pTab)); continue; } if( i>0 && zTName==0 ){ | < | | > | | | 3211 3212 3213 3214 3215 3216 3217 3218 3219 3220 3221 3222 3223 3224 3225 3226 3227 3228 3229 3230 3231 3232 | */ if( IsHiddenColumn(&pTab->aCol[j]) ){ assert(IsVirtual(pTab)); continue; } if( i>0 && zTName==0 ){ if( (pFrom->jointype & JT_NATURAL)!=0 && tableAndColumnIndex(pTabList, i, zName, 0, 0) ){ /* In a NATURAL join, omit the join columns from the ** table to the right of the join */ continue; } if( sqlite3IdListIndex(pFrom->pUsing, zName)>=0 ){ /* In a join with a USING clause, omit columns in the ** using clause from the table on the right. */ continue; } } pRight = sqlite3Expr(db, TK_ID, zName); zColname = zName; |
︙ | ︙ |