/ Check-in [c54ad212]
Login

Many hyperlinks are disabled.
Use anonymous login to enable hyperlinks.

Overview
Comment:Fix a buggy interaction between "INSERT ... SELECT" processing and optimization (2170). (CVS 2319)
Downloads: Tarball | ZIP archive | SQL archive
Timelines: family | ancestors | descendants | both | trunk
Files: files | file ages | folders
SHA1: c54ad2123693be8777d80343979e3261c4892105
User & Date: danielk1977 2005-02-08 08:42:28
Context
2005-02-09
01:40
Document SQLITE_DEFAULT_CACHE_SIZE and SQLITE_DEFAULT_TEMP_CACHE_SIZE macros. (CVS 2320) check-in: ddcea6f8 user: danielk1977 tags: trunk
2005-02-08
08:42
Fix a buggy interaction between "INSERT ... SELECT" processing and optimization (2170). (CVS 2319) check-in: c54ad212 user: danielk1977 tags: trunk
07:50
Fix for correlated subqueries where the parent is an aggregate. Ticket #1105. (CVS 2318) check-in: f0d3ca10 user: danielk1977 tags: trunk
Changes
Hide Diffs Unified Diffs Ignore Whitespace Patch

Changes to src/insert.c.

8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
..
90
91
92
93
94
95
96





















97
98
99
100
101
102
103
...
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
...
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
**    May you find forgiveness for yourself and forgive others.
**    May you share freely, never taking more than you give.
**
*************************************************************************
** This file contains C code routines that are called by the parser
** to handle INSERT statements in SQLite.
**
** $Id: insert.c,v 1.135 2005/01/29 08:32:45 danielk1977 Exp $
*/
#include "sqliteInt.h"

/*
** Set P3 of the most recently inserted opcode to a column affinity
** string for index pIdx. A column affinity string has one character
** for each column in the table, according to the affinity of the column:
................................................................................

    pTab->zColAff = zColAff;
  }

  sqlite3VdbeChangeP3(v, -1, pTab->zColAff, 0);
}























/*
** This routine is call to handle SQL of the following forms:
**
**    insert into TABLE (IDLIST) values(EXPRLIST)
**    insert into TABLE (IDLIST) select
**
................................................................................
  Index *pIdx;          /* For looping over indices of the table */
  int nColumn;          /* Number of columns in the data */
  int base = 0;         /* VDBE Cursor number for pTab */
  int iCont=0,iBreak=0; /* Beginning and end of the loop over srcTab */
  sqlite3 *db;          /* The main database structure */
  int keyColumn = -1;   /* Column that is the INTEGER PRIMARY KEY */
  int endOfLoop;        /* Label for the end of the insertion loop */
  int useTempTable;     /* Store SELECT results in intermediate table */
  int srcTab = 0;       /* Data comes from this temporary cursor if >=0 */
  int iSelectLoop = 0;  /* Address of code that implements the SELECT */
  int iCleanup = 0;     /* Address of the cleanup code */
  int iInsertBlock = 0; /* Address of the subroutine used to insert data */
  int iCntMem = 0;      /* Memory cell used for the row counter */
  int newIdx = -1;      /* Cursor for the NEW table */
  Db *pDb;              /* The database containing table being inserted into */
................................................................................
    ** should be written into a temporary table.  Set to FALSE if each
    ** row of the SELECT can be written directly into the result table.
    **
    ** A temp table must be used if the table being updated is also one
    ** of the tables being read by the SELECT statement.  Also use a 
    ** temp table in the case of row triggers.
    */
    if( triggers_exist ){
      useTempTable = 1;
    }else{
      int addr = 0;
      useTempTable = 0;
      while( useTempTable==0 ){
        VdbeOp *pOp;
        addr = sqlite3VdbeFindOp(v, addr, OP_OpenRead, pTab->tnum);
        if( addr==0 ) break;
        pOp = sqlite3VdbeGetOp(v, addr-2);
        if( pOp->opcode==OP_Integer && pOp->p1==pTab->iDb ){
          useTempTable = 1;
        }
      }
    }

    if( useTempTable ){
      /* Generate the subroutine that SELECT calls to process each row of
      ** the result.  Store the result in a temporary table
      */
      srcTab = pParse->nTab++;







|







 







>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>







 







|







 







|

<
<
<
<
<
<
<
<
<
<
<
<







8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
..
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
...
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
...
347
348
349
350
351
352
353
354
355












356
357
358
359
360
361
362
**    May you find forgiveness for yourself and forgive others.
**    May you share freely, never taking more than you give.
**
*************************************************************************
** This file contains C code routines that are called by the parser
** to handle INSERT statements in SQLite.
**
** $Id: insert.c,v 1.136 2005/02/08 08:42:28 danielk1977 Exp $
*/
#include "sqliteInt.h"

/*
** Set P3 of the most recently inserted opcode to a column affinity
** string for index pIdx. A column affinity string has one character
** for each column in the table, according to the affinity of the column:
................................................................................

    pTab->zColAff = zColAff;
  }

  sqlite3VdbeChangeP3(v, -1, pTab->zColAff, 0);
}

/*
** 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.
*/
static int selectReadsTable(Select *p, int iDb, int iTab){
  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(p, iDb, iTab) ) return 1;
    }else{
      if( pItem->pTab->iDb==iDb && pItem->pTab->tnum==iTab ) return 1;
    }
  }
  return 0;
}

/*
** This routine is call to handle SQL of the following forms:
**
**    insert into TABLE (IDLIST) values(EXPRLIST)
**    insert into TABLE (IDLIST) select
**
................................................................................
  Index *pIdx;          /* For looping over indices of the table */
  int nColumn;          /* Number of columns in the data */
  int base = 0;         /* VDBE Cursor number for pTab */
  int iCont=0,iBreak=0; /* Beginning and end of the loop over srcTab */
  sqlite3 *db;          /* The main database structure */
  int keyColumn = -1;   /* Column that is the INTEGER PRIMARY KEY */
  int endOfLoop;        /* Label for the end of the insertion loop */
  int useTempTable = 0; /* Store SELECT results in intermediate table */
  int srcTab = 0;       /* Data comes from this temporary cursor if >=0 */
  int iSelectLoop = 0;  /* Address of code that implements the SELECT */
  int iCleanup = 0;     /* Address of the cleanup code */
  int iInsertBlock = 0; /* Address of the subroutine used to insert data */
  int iCntMem = 0;      /* Memory cell used for the row counter */
  int newIdx = -1;      /* Cursor for the NEW table */
  Db *pDb;              /* The database containing table being inserted into */
................................................................................
    ** should be written into a temporary table.  Set to FALSE if each
    ** row of the SELECT can be written directly into the result table.
    **
    ** A temp table must be used if the table being updated is also one
    ** 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->iDb, pTab->tnum) ){
      useTempTable = 1;












    }

    if( useTempTable ){
      /* Generate the subroutine that SELECT calls to process each row of
      ** the result.  Store the result in a temporary table
      */
      srcTab = pParse->nTab++;

Changes to test/insert2.test.

8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
...
240
241
242
243
244
245
246




















247

#    May you share freely, never taking more than you give.
#
#***********************************************************************
# This file implements regression tests for SQLite library.  The
# focus of this file is testing the INSERT statement that takes is
# result from a SELECT.
#
# $Id: insert2.test,v 1.14 2005/01/21 03:12:16 danielk1977 Exp $

set testdir [file dirname $argv0]
source $testdir/tester.tcl

# Create some tables with data that we can select against
#
do_test insert2-1.0 {
................................................................................
           DepCheck.name == Dependencies.name AND 
           DepCheck.flag == Dependencies.flag 
       WHERE 
           Dependencies.depId is NULL;
  };
} {}





















finish_test








|







 







>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>

>
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
...
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
265
266
267
268
#    May you share freely, never taking more than you give.
#
#***********************************************************************
# This file implements regression tests for SQLite library.  The
# focus of this file is testing the INSERT statement that takes is
# result from a SELECT.
#
# $Id: insert2.test,v 1.15 2005/02/08 08:42:29 danielk1977 Exp $

set testdir [file dirname $argv0]
source $testdir/tester.tcl

# Create some tables with data that we can select against
#
do_test insert2-1.0 {
................................................................................
           DepCheck.name == Dependencies.name AND 
           DepCheck.flag == Dependencies.flag 
       WHERE 
           Dependencies.depId is NULL;
  };
} {}

#--------------------------------------------------------------------
# Test that the INSERT works when the SELECT statement (a) references
# the table being inserted into and (b) is optimized to use an index
# only.
do_test insert2-5.1 {
  execsql {
    CREATE TABLE t2(a, b);
    INSERT INTO t2 VALUES(1, 2);
    CREATE INDEX t2i1 ON t2(a);
    INSERT INTO t2 SELECT a, 3 FROM t2 WHERE a = 1;
    SELECT * FROM t2;
  }
} {1 2 1 3}
do_test insert2-5.2 {
  execsql {
    INSERT INTO t2 SELECT (SELECT a FROM t2), 4;
    SELECT * FROM t2;
  }
} {1 2 1 3 1 4}

finish_test