Make sure that INSERT INTO ... SELECT ... always uses an ephemeral

intermediate table if the SELECT clause refers to the destination table,
even if the SELECT clause is compound or uses the destination table
in a subquery.  This fixes a long-standing bug that can cause an
infinite loop for some SQL statements. (CVS 4552)

FossilOrigin-Name: 492b39b6a8bf4ad8792d7a7949f77827a5047fd8
This commit is contained in:
drh 2007-11-23 15:02:19 +00:00
parent f4ce8ed048
commit 48d1178ad8
4 changed files with 132 additions and 24 deletions

View File

@ -1,5 +1,5 @@
C Avoid\sa\sdouble-free\sin\san\sout-of-memory\ssituation\swith\sa\sUSING\nclause\sor\sNATURAL\sJOIN.\s\sTicket\s#2789.\s(CVS\s4551)
D 2007-11-23T13:42:52
C Make\ssure\sthat\sINSERT\sINTO\s...\sSELECT\s...\salways\suses\san\sephemeral\r\nintermediate\stable\sif\sthe\sSELECT\sclause\srefers\sto\sthe\sdestination\stable,\r\neven\sif\sthe\sSELECT\sclause\sis\scompound\sor\suses\sthe\sdestination\stable\r\nin\sa\ssubquery.\s\sThis\sfixes\sa\slong-standing\sbug\sthat\scan\scause\san\r\ninfinite\sloop\sfor\ssome\sSQL\sstatements.\s(CVS\s4552)
D 2007-11-23T15:02:19
F Makefile.arm-wince-mingw32ce-gcc ac5f7b2cef0cd850d6f755ba6ee4ab961b1fadf7
F Makefile.in 30c7e3ba426ddb253b8ef037d1873425da6009a8
F Makefile.linux-gcc d53183f4aa6a9192d249731c90dbdffbd2c68654
@ -95,7 +95,7 @@ F src/expr.c 7977bb9680ebeeabfa3214d936778baaa26dcc0c
F src/func.c 73b4974e5ff03cc71345cc3a33b0022f7b99974a
F src/hash.c 45a7005aac044b6c86bd7e49c44bc15d30006d6c
F src/hash.h 031cd9f915aff27e12262cb9eb570ac1b8326b53
F src/insert.c df9712e1f67201573a9677d3a2fe401d52d84dda
F src/insert.c 86fe24ca954b6b3b6c32d05e5aa17387f244cfbb
F src/journal.c 807bed7a158979ac8d63953e1774e8d85bff65e2
F src/legacy.c 4ac53191fad2e3c4d59bde1228879b2dc5a96d66
F src/limits.h 71ab25f17e35e0a9f3f6f234b8ed49cc56731d35
@ -331,6 +331,7 @@ F test/insert.test aef273dd1cee84cc92407469e6bd1b3cdcb76908
F test/insert2.test 5a20e1ace5fa0800b58d28284212290189b49aed
F test/insert3.test 9a4ef3526fd3cca8b05278020ec3100448b4c677
F test/insert4.test 6919ddacd79c2cfeb9785b0f84217f9cb14853b5
F test/insert5.test e8d5ba31283db5b0315ada9774dd99b6e9fe2122
F test/interrupt.test 81555fb0f8179bb2d0dc7151fd75428223f93cf2
F test/intpkey.test af4fd826c4784ec5c93b444de07adea0254d0d30
F test/io.test 835b0ec66166312ff743e2fd11a878c65068de9f
@ -588,7 +589,7 @@ F www/tclsqlite.tcl 8be95ee6dba05eabcd27a9d91331c803f2ce2130
F www/vdbe.tcl 87a31ace769f20d3627a64fa1fade7fed47b90d0
F www/version3.tcl 890248cf7b70e60c383b0e84d77d5132b3ead42b
F www/whentouse.tcl fc46eae081251c3c181bd79c5faef8195d7991a5
P 247fa2eac0789be48cae3587643ab07576ae7b76
R fadab18fb0a0bf50417bc8c670c993f9
P 596694752c5935ae50ad38d3b41bbda39ca999d8
R 20a8f4025ce189436d5177ee5388d030
U drh
Z 099e4af1d341dbdcd9f41e78699e9abe
Z 5100bd3ff118635e492cb0995aacacc3

View File

@ -1 +1 @@
596694752c5935ae50ad38d3b41bbda39ca999d8
492b39b6a8bf4ad8792d7a7949f77827a5047fd8

View File

@ -12,7 +12,7 @@
** This file contains C code routines that are called by the parser
** to handle INSERT statements in SQLite.
**
** $Id: insert.c,v 1.192 2007/09/03 17:30:07 danielk1977 Exp $
** $Id: insert.c,v 1.193 2007/11/23 15:02:19 drh Exp $
*/
#include "sqliteInt.h"
@ -99,22 +99,38 @@ void sqlite3TableAffinityStr(Vdbe *v, Table *pTab){
}
/*
** Return non-zero if SELECT statement p opens the table with rootpage
** iTab in database iDb. This is used to see if a statement of the form
** "INSERT INTO <iDb, iTab> SELECT ..." can run without using temporary
** table for the results of the SELECT.
**
** No checking is done for sub-selects that are part of expressions.
** Return non-zero if the table pTab in database iDb or any of its indices
** have been opened at any point in the VDBE program beginning at location
** iStartAddr throught the end of the program. This is used to see if
** a statement of the form "INSERT INTO <iDb, pTab> SELECT ..." can
** run without using temporary table for the results of the SELECT.
*/
static int selectReadsTable(Select *p, Schema *pSchema, int iTab){
static int readsTable(Vdbe *v, int iStartAddr, int iDb, Table *pTab){
int i;
struct SrcList_item *pItem;
if( p->pSrc==0 ) return 0;
for(i=0, pItem=p->pSrc->a; i<p->pSrc->nSrc; i++, pItem++){
if( pItem->pSelect ){
if( selectReadsTable(pItem->pSelect, pSchema, iTab) ) return 1;
}else{
if( pItem->pTab->pSchema==pSchema && pItem->pTab->tnum==iTab ) return 1;
int iEnd = sqlite3VdbeCurrentAddr(v);
for(i=iStartAddr; i<iEnd; i++){
VdbeOp *pOp = sqlite3VdbeGetOp(v, i);
if( pOp->opcode==OP_OpenRead ){
VdbeOp *pPrior = &pOp[-1];
int tnum = pOp->p2;
assert( i>iStartAddr );
assert( pPrior->opcode==OP_Integer );
if( pPrior->p1==iDb ){
Index *pIndex;
if( tnum==pTab->tnum ){
return 1;
}
for(pIndex=pTab->pIndex; pIndex; pIndex=pIndex->pNext){
if( tnum==pIndex->tnum ){
return 1;
}
}
}
}
if( pOp->opcode==OP_VOpen && pOp->p3==(const char*)pTab->pVtab ){
assert( pOp->p3!=0 );
assert( pOp->p3type==P3_VTAB );
return 1;
}
}
return 0;
@ -481,7 +497,7 @@ void sqlite3Insert(
** of the tables being read by the SELECT statement. Also use a
** temp table in the case of row triggers.
*/
if( triggers_exist || selectReadsTable(pSelect,pTab->pSchema,pTab->tnum) ){
if( triggers_exist || readsTable(v, iSelectLoop, iDb, pTab) ){
useTempTable = 1;
}
@ -517,7 +533,7 @@ void sqlite3Insert(
memset(&sNC, 0, sizeof(sNC));
sNC.pParse = pParse;
srcTab = -1;
useTempTable = 0;
assert( useTempTable==0 );
nColumn = pList ? pList->nExpr : 0;
for(i=0; i<nColumn; i++){
if( sqlite3ExprResolveNames(&sNC, pList->a[i].pExpr) ){

91
test/insert5.test Normal file
View File

@ -0,0 +1,91 @@
# 2007 November 23
#
# 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.
#
#***********************************************************************
#
# The tests in this file ensure that a temporary table is used
# when required by an "INSERT INTO ... SELECT ..." statement.
#
# $Id: insert5.test,v 1.1 2007/11/23 15:02:19 drh Exp $
set testdir [file dirname $argv0]
source $testdir/tester.tcl
# Return true if the compilation of the sql passed as an argument
# includes the opcode OpenEphemeral. An "INSERT INTO ... SELECT"
# statement includes such an opcode if a temp-table is used
# to store intermediate results.
#
proc uses_temp_table {sql} {
return [expr {[lsearch [execsql "EXPLAIN $sql"] OpenEphemeral]>=0}]
}
# Construct the sample database.
#
do_test insert5-1.0 {
file delete -force test2.db test2.db-journal
execsql {
CREATE TABLE MAIN(Id INTEGER, Id1 INTEGER);
CREATE TABLE B(Id INTEGER, Id1 INTEGER);
CREATE VIEW v1 AS SELECT * FROM B;
CREATE VIEW v2 AS SELECT * FROM MAIN;
INSERT INTO MAIN(Id,Id1) VALUES(2,3);
INSERT INTO B(Id,Id1) VALUES(2,3);
}
} {}
# Run the query.
#
do_test insert5-1.1 {
execsql {
INSERT INTO B
SELECT * FROM B UNION ALL
SELECT * FROM MAIN WHERE exists (select * FROM B WHERE B.Id = MAIN.Id);
SELECT * FROM B;
}
} {2 3 2 3 2 3}
do_test insert5-2.1 {
uses_temp_table { INSERT INTO b SELECT * FROM main }
} {0}
do_test insert5-2.2 {
uses_temp_table { INSERT INTO b SELECT * FROM b }
} {1}
do_test insert5-2.3 {
uses_temp_table { INSERT INTO b SELECT (SELECT id FROM b), id1 FROM main }
} {1}
do_test insert5-2.4 {
uses_temp_table { INSERT INTO b SELECT id1, (SELECT id FROM b) FROM main }
} {1}
do_test insert5-2.5 {
uses_temp_table {
INSERT INTO b
SELECT * FROM main WHERE id = (SELECT id1 FROM b WHERE main.id = b.id) }
} {1}
do_test insert5-2.6 {
uses_temp_table { INSERT INTO b SELECT * FROM v1 }
} {1}
do_test insert5-2.7 {
uses_temp_table { INSERT INTO b SELECT * FROM v2 }
} {0}
do_test insert5-2.8 {
uses_temp_table {
INSERT INTO b
SELECT * FROM main WHERE id > 10 AND max(id1, (SELECT id FROM b)) > 10;
}
} {1}
do_test insert5-2.9 {
uses_temp_table {
INSERT INTO b
SELECT * FROM main
WHERE id > 10 AND (SELECT count(*) FROM v2 GROUP BY main.id)
}
} {1}
finish_test