Added ON CONFLICT support to COPY. Updates to documentation. Bug fixes. (CVS 359)
FossilOrigin-Name: cf1538d71c9ce12d5e59f367e03642cbcaf6b717
This commit is contained in:
parent
ef6764a1d9
commit
b419a926d4
@ -343,6 +343,9 @@ faq.html: $(TOP)/www/faq.tcl
|
||||
formatchng.html: $(TOP)/www/formatchng.tcl
|
||||
tclsh $(TOP)/www/formatchng.tcl >formatchng.html
|
||||
|
||||
conflict.html: $(TOP)/www/conflict.tcl
|
||||
tclsh $(TOP)/www/conflict.tcl >conflict.html
|
||||
|
||||
download.html: $(TOP)/www/download.tcl
|
||||
tclsh $(TOP)/www/download.tcl >download.html
|
||||
|
||||
@ -365,7 +368,8 @@ DOC = \
|
||||
download.html \
|
||||
speed.html \
|
||||
faq.html \
|
||||
formatchng.html
|
||||
formatchng.html \
|
||||
conflict.html
|
||||
|
||||
doc: $(DOC)
|
||||
mkdir -p doc
|
||||
|
35
manifest
35
manifest
@ -1,7 +1,7 @@
|
||||
C Better\stesting\sof\sthe\sON\sCONFLICT\slogic.\s(CVS\s358)
|
||||
D 2002-01-30T04:32:01
|
||||
C Added\sON\sCONFLICT\ssupport\sto\sCOPY.\sUpdates\sto\sdocumentation.\sBug\sfixes.\s(CVS\s359)
|
||||
D 2002-01-30T16:17:24
|
||||
F Makefile.in 9fa4277413bf1d9cf91365f07d4108d7d87ed2af
|
||||
F Makefile.template 3e26a3b9e7aee1b811deaf673e8d8973bdb3f22d
|
||||
F Makefile.template 3372d45f8853afdb70bd30cc6fb50a3cd9069834
|
||||
F README a4c0ba11354ef6ba0776b400d057c59da47a4cc0
|
||||
F VERSION 34f7c904a063d2d3791c38521e40ae1648cd2e7e
|
||||
F aclocal.m4 11faa843caa38fd451bc6aeb43e248d1723a269d
|
||||
@ -21,35 +21,35 @@ F sqlite.1 2e2bb0529ef468ade9e4322bd609d0695fb9ded9
|
||||
F src/TODO af7f3cab0228e34149cf98e073aa83d45878e7e6
|
||||
F src/btree.c c796e387da340cb628dc1e41f684fc20253f561e
|
||||
F src/btree.h 9ead7f54c270d8a554e59352ca7318fdaf411390
|
||||
F src/build.c c55881f270b1a77d1025dcfba7c87db46d43a9d0
|
||||
F src/build.c 78571589a39d4b03b19b1300db8b23f1d3e1bab2
|
||||
F src/delete.c 4cdb6d2e94e2eb1b1aa79eefafd4669d43c249d6
|
||||
F src/expr.c a2a87dbd411a508ff89dffa90505ad42dac2f920
|
||||
F src/hash.c 8f7c740ef2eaaa8decfa8751f2be30680b123e46
|
||||
F src/hash.h a5f5b3ce2d086a172c5879b0b06a27a82eac9fac
|
||||
F src/insert.c 5de9d85889d4b97c823be1b9ebf01c30e29947b3
|
||||
F src/insert.c 37971598f1cbfc9de9bd1d269529e233003652b8
|
||||
F src/main.c 0205771a6c31a9858ff131fc1e797b589afb76bf
|
||||
F src/md5.c 52f677bfc590e09f71d07d7e327bd59da738d07c
|
||||
F src/os.c c615faa4d23e742e0650e0751a6ad2a18438ad53
|
||||
F src/os.h 5405a5695bf16889d4fc6caf9d42043caa41c269
|
||||
F src/pager.c 1e80a3ba731e454df6bd2e58d32eeba7dd65121b
|
||||
F src/pager.h f78d064c780855ff70beacbeba0e2324471b26fe
|
||||
F src/parse.y fd79a09265b4703e37a62084db6fe67c834defb4
|
||||
F src/parse.y e80f1cf6a280e3da0f49c9b60b14edc2f15912ec
|
||||
F src/printf.c 300a90554345751f26e1fc0c0333b90a66110a1d
|
||||
F src/random.c f6b36bec5ebd3edb3440224bf5bf811fe4ac9a1b
|
||||
F src/select.c fc11d5a8c2bae1b62d8028ffb111c773ad6bf161
|
||||
F src/shell.c c102dfe388c7618a668c944ff157c49cb48f28e3
|
||||
F src/shell.tcl 27ecbd63dd88396ad16d81ab44f73e6c0ea9d20e
|
||||
F src/sqlite.h.in f57074c84a2c112a5093ba7a9d9636aa9cacc87c
|
||||
F src/sqliteInt.h 60c0945eb4159c44adec9aadadb61dfd931d29e9
|
||||
F src/sqliteInt.h 3bf0938d01e1cc57154c39c730d7e91d9bd60359
|
||||
F src/table.c c89698bd5bb4b8d14722d6ee7e9be014c383d24a
|
||||
F src/tclsqlite.c b9cf346e95291cb4c4f1bf5ac1d77db6b8ad023d
|
||||
F src/test1.c 33efd350dca27c52c58c553c04fd3a6a51f13c1f
|
||||
F src/test2.c e9f99aa5ee73872819259d6612c11e55e1644321
|
||||
F src/test3.c d6775f95fd91f5b3cf0e2382a28e5aaeb68f745b
|
||||
F src/tokenize.c 1199b96a82d5c41509b5e24fc9faa1852b7f3135
|
||||
F src/update.c 5ffd4bbd380f1fa99da184f28416e6dcf8b5508e
|
||||
F src/update.c c6215079d7604fd1cf785eff64ec0e03e97bd138
|
||||
F src/util.c 8f8973dd55a6ec63be9632fc5de86965c99d6327
|
||||
F src/vdbe.c 893fa634870a5ea67c30ba61b7881b537f5c2723
|
||||
F src/vdbe.c 14667d889d9d9ebdc5f5f5d030312071f41b7873
|
||||
F src/vdbe.h 5b1bd518126fc5a30e6ea13fe11de931b32c4b59
|
||||
F src/where.c 2dda39367f193194e4c7d2e0dcab31527d9d8aba
|
||||
F test/all.test 2a51e5395ac7c2c539689b123b9782a05e3837fe
|
||||
@ -57,8 +57,8 @@ F test/bigrow.test 8ab252dba108f12ad64e337b0f2ff31a807ac578
|
||||
F test/btree.test 6ab4dc5f595905a276ef588fad3c9236dc07a47b
|
||||
F test/btree2.test 08e9485619265cbaf5d11bd71f357cdc26bb87e0
|
||||
F test/btree3.test 9caa9e22491dd8cd8aa36d7ac3b48b089817c895
|
||||
F test/conflict.test 66ac8bec8e25224b6aca18d76dd40b0afa27e227
|
||||
F test/copy.test 768e6f1701a07d08090e1ca7f7dcce0a7a72b43e
|
||||
F test/conflict.test 685725a37ec13e671ec57f48285c1c08bba21c99
|
||||
F test/copy.test 4079990fb84be696d29c43de9fa6492312f165f0
|
||||
F test/delete.test c904a62129fe102b314a96111a8417f10249e4d8
|
||||
F test/expr.test c8a495050dcec3f9e68538c3ef466726933302c1
|
||||
F test/func.test 51dbe3f8a4c28972751697423e6acc5d6b551df1
|
||||
@ -107,21 +107,22 @@ F www/arch.fig d5f9752a4dbf242e9cfffffd3f5762b6c63b3bcf
|
||||
F www/arch.png 82ef36db1143828a7abc88b1e308a5f55d4336f4
|
||||
F www/arch.tcl 72a0c80e9054cc7025a50928d28d9c75c02c2b8b
|
||||
F www/c_interface.tcl 82a026b1681757f13b3f62e035f3a31407c1d353
|
||||
F www/changes.tcl 6b802e152436c7596308b6a4901e91415be0d9d4
|
||||
F www/changes.tcl 3770ded78faa7a634b55fbf5316caa4cb150e5f9
|
||||
F www/conflict.tcl 3f70c01680b8d763bf3305eb67f6d85fdf83b497
|
||||
F www/crosscompile.tcl 3622ebbe518927a3854a12de51344673eb2dd060
|
||||
F www/download.tcl 1ea61f9d89a2a5a9b2cee36b0d5cf97321bdefe0
|
||||
F www/dynload.tcl 02eb8273aa78cfa9070dd4501dca937fb22b466c
|
||||
F www/faq.tcl 32cbc134879871604070d4cc3a32e73fb22a35f9
|
||||
F www/formatchng.tcl d96e5e937dcbbebd481720aa08745ca5a906a63f
|
||||
F www/formatchng.tcl 2d9a35c787823b48d72a5c64bb5414a43e26d5ad
|
||||
F www/index.tcl 748614d8208c761ed3840e7958b8eed04de81822
|
||||
F www/lang.tcl 6843fd3f85cba95fd199a350533ce742c706603c
|
||||
F www/lang.tcl f04d74017e627f6f133438234bd20fbe585ca4cf
|
||||
F www/mingw.tcl f1c7c0a7f53387dd9bb4f8c7e8571b7561510ebc
|
||||
F www/opcode.tcl bdec8ef9f100dbd87bbef8976c54b88e43fd8ccc
|
||||
F www/speed.tcl 83457b2bf6bb430900bd48ca3dd98264d9a916a5
|
||||
F www/sqlite.tcl 8b5884354cb615049aed83039f8dfe1552a44279
|
||||
F www/tclsqlite.tcl 829b393d1ab187fd7a5e978631b3429318885c49
|
||||
F www/vdbe.tcl 2013852c27a02a091d39a766bc87cff329f21218
|
||||
P 8229b5f6a348a56432a4a609ee125520c5831973
|
||||
R 6092c649bf38d0cb57a1ec35caeb9370
|
||||
P 9bbddb8e013b47547164f71f2d7abd995f8d7385
|
||||
R ad077c176de250ed6687e2b5636281f6
|
||||
U drh
|
||||
Z 733d233a561b4a44b1706a6a61fc3f4e
|
||||
Z 1ba7e7bec405961a534e04fc39ece2b3
|
||||
|
@ -1 +1 @@
|
||||
9bbddb8e013b47547164f71f2d7abd995f8d7385
|
||||
cf1538d71c9ce12d5e59f367e03642cbcaf6b717
|
32
src/build.c
32
src/build.c
@ -25,7 +25,7 @@
|
||||
** ROLLBACK
|
||||
** PRAGMA
|
||||
**
|
||||
** $Id: build.c,v 1.68 2002/01/29 23:07:02 drh Exp $
|
||||
** $Id: build.c,v 1.69 2002/01/30 16:17:24 drh Exp $
|
||||
*/
|
||||
#include "sqliteInt.h"
|
||||
#include <ctype.h>
|
||||
@ -1332,7 +1332,8 @@ void sqliteCopy(
|
||||
Parse *pParse, /* The parser context */
|
||||
Token *pTableName, /* The name of the table into which we will insert */
|
||||
Token *pFilename, /* The file from which to obtain information */
|
||||
Token *pDelimiter /* Use this as the field delimiter */
|
||||
Token *pDelimiter, /* Use this as the field delimiter */
|
||||
int onError /* What to do if a constraint fails */
|
||||
){
|
||||
Table *pTab;
|
||||
char *zTab;
|
||||
@ -1376,6 +1377,9 @@ void sqliteCopy(
|
||||
sqliteVdbeAddOp(v, openOp, i, pIdx->tnum);
|
||||
sqliteVdbeChangeP3(v, -1, pIdx->zName, P3_STATIC);
|
||||
}
|
||||
if( db->flags & SQLITE_CountRows ){
|
||||
sqliteVdbeAddOp(v, OP_Integer, 0, 0); /* Initialize the row count */
|
||||
}
|
||||
end = sqliteVdbeMakeLabel(v);
|
||||
addr = sqliteVdbeAddOp(v, OP_FileRead, pTab->nCol, end);
|
||||
if( pDelimiter ){
|
||||
@ -1390,9 +1394,6 @@ void sqliteCopy(
|
||||
}else{
|
||||
sqliteVdbeAddOp(v, OP_NewRecno, 0, 0);
|
||||
}
|
||||
if( pTab->pIndex ){
|
||||
sqliteVdbeAddOp(v, OP_Dup, 0, 0);
|
||||
}
|
||||
for(i=0; i<pTab->nCol; i++){
|
||||
if( i==pTab->iPKey ){
|
||||
/* The integer primary key column is filled with NULL since its
|
||||
@ -1402,17 +1403,10 @@ void sqliteCopy(
|
||||
sqliteVdbeAddOp(v, OP_FileColumn, i, 0);
|
||||
}
|
||||
}
|
||||
sqliteVdbeAddOp(v, OP_MakeRecord, pTab->nCol, 0);
|
||||
sqliteVdbeAddOp(v, OP_PutIntKey, 0, 0);
|
||||
for(i=1, pIdx=pTab->pIndex; pIdx; pIdx=pIdx->pNext, i++){
|
||||
if( pIdx->pNext ){
|
||||
sqliteVdbeAddOp(v, OP_Dup, 0, 0);
|
||||
}
|
||||
for(j=0; j<pIdx->nColumn; j++){
|
||||
sqliteVdbeAddOp(v, OP_FileColumn, pIdx->aiColumn[j], 0);
|
||||
}
|
||||
sqliteVdbeAddOp(v, OP_MakeIdxKey, pIdx->nColumn, 0);
|
||||
sqliteVdbeAddOp(v, OP_IdxPut, i, pIdx->onError!=OE_None);
|
||||
sqliteGenerateConstraintChecks(pParse, pTab, 0, 0, 0, 0, onError, addr);
|
||||
sqliteCompleteInsertion(pParse, pTab, 0, 0, 0, 0);
|
||||
if( (db->flags & SQLITE_CountRows)!=0 ){
|
||||
sqliteVdbeAddOp(v, OP_AddImm, 1, 0); /* Increment row count */
|
||||
}
|
||||
sqliteVdbeAddOp(v, OP_Goto, 0, addr);
|
||||
sqliteVdbeResolveLabel(v, end);
|
||||
@ -1420,6 +1414,12 @@ void sqliteCopy(
|
||||
if( (db->flags & SQLITE_InTrans)==0 ){
|
||||
sqliteVdbeAddOp(v, OP_Commit, 0, 0);
|
||||
}
|
||||
if( db->flags & SQLITE_CountRows ){
|
||||
sqliteVdbeAddOp(v, OP_ColumnCount, 1, 0);
|
||||
sqliteVdbeAddOp(v, OP_ColumnName, 0, 0);
|
||||
sqliteVdbeChangeP3(v, -1, "rows inserted", P3_STATIC);
|
||||
sqliteVdbeAddOp(v, OP_Callback, 1, 0);
|
||||
}
|
||||
}
|
||||
|
||||
copy_cleanup:
|
||||
|
50
src/insert.c
50
src/insert.c
@ -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.37 2002/01/30 04:32:01 drh Exp $
|
||||
** $Id: insert.c,v 1.38 2002/01/30 16:17:24 drh Exp $
|
||||
*/
|
||||
#include "sqliteInt.h"
|
||||
|
||||
@ -202,9 +202,7 @@ void sqliteInsert(
|
||||
/* Push the record number for the new entry onto the stack. The
|
||||
** record number is a randomly generate integer created by NewRecno
|
||||
** except when the table has an INTEGER PRIMARY KEY column, in which
|
||||
** case the record number is the same as that column. May a copy
|
||||
** because sqliteGenerateConstraintChecks() requires two copies of
|
||||
** the record number.
|
||||
** case the record number is the same as that column.
|
||||
*/
|
||||
if( keyColumn>=0 ){
|
||||
if( srcTab>=0 ){
|
||||
@ -216,7 +214,6 @@ void sqliteInsert(
|
||||
}else{
|
||||
sqliteVdbeAddOp(v, OP_NewRecno, base, 0);
|
||||
}
|
||||
sqliteVdbeAddOp(v, OP_Dup, 0, 0);
|
||||
|
||||
/* Push onto the stack, data for all columns of the new entry, beginning
|
||||
** with the first column.
|
||||
@ -251,8 +248,8 @@ void sqliteInsert(
|
||||
** do the insertion.
|
||||
*/
|
||||
endOfLoop = sqliteVdbeMakeLabel(v);
|
||||
sqliteGenerateConstraintChecks(pParse, pTab, base, 0,1,onError,endOfLoop,0);
|
||||
sqliteCompleteInsertion(pParse, pTab, base, 0, 1);
|
||||
sqliteGenerateConstraintChecks(pParse, pTab, base, 0,0,0, onError, endOfLoop);
|
||||
sqliteCompleteInsertion(pParse, pTab, base, 0,0,0);
|
||||
|
||||
/* If inserting from a SELECT, keep a count of the number of
|
||||
** rows inserted.
|
||||
@ -302,11 +299,11 @@ insert_cleanup:
|
||||
** When this routine is called, the stack contains (from bottom to top)
|
||||
** the following values:
|
||||
**
|
||||
** 1. The recno of the row to be updated before it is updated.
|
||||
** 1. The recno of the row to be updated before it is updated. This
|
||||
** value is omitted unless we are doing an UPDATE that involves a
|
||||
** change to the record number.
|
||||
**
|
||||
** 2. The recno of the row after the update. (This is usually the
|
||||
** same as (1) but can be different if an UPDATE changes an
|
||||
** INTEGER PRIMARY KEY column.)
|
||||
** 2. The recno of the row after the update.
|
||||
**
|
||||
** 3. The data in the first column of the entry after the update.
|
||||
**
|
||||
@ -314,9 +311,9 @@ insert_cleanup:
|
||||
**
|
||||
** N. The data in the last column of the entry after the update.
|
||||
**
|
||||
** The old recno shown as entry (1) above is omitted if the recnoChng
|
||||
** parameter is 0. recnoChange is true if the record number is changing
|
||||
** and false if not.
|
||||
** The old recno shown as entry (1) above is omitted unless both isUpdate
|
||||
** and recnoChng are both 1. isUpdate is true for UPDATEs and false for
|
||||
** INSERTs and recnoChng is ture if the record number is being changed.
|
||||
**
|
||||
** The code generated by this routine pushes additional entries onto
|
||||
** the stack which are the keys for new index entries for the new record.
|
||||
@ -373,9 +370,9 @@ void sqliteGenerateConstraintChecks(
|
||||
int base, /* Index of a read/write cursor pointing at pTab */
|
||||
char *aIdxUsed, /* Which indices are used. NULL means all are used */
|
||||
int recnoChng, /* True if the record number will change */
|
||||
int isUpdate, /* True for UPDATE, False for INSERT */
|
||||
int overrideError, /* Override onError to this if not OE_Default */
|
||||
int ignoreDest, /* Jump to this label on an OE_Ignore resolution */
|
||||
int isUpdate /* True for UPDATE, False for INSERT */
|
||||
int ignoreDest /* Jump to this label on an OE_Ignore resolution */
|
||||
){
|
||||
int i;
|
||||
Vdbe *v;
|
||||
@ -388,11 +385,11 @@ void sqliteGenerateConstraintChecks(
|
||||
int seenReplace = 0;
|
||||
int jumpInst;
|
||||
int contAddr;
|
||||
int hasTwoRecnos = (isUpdate && recnoChng);
|
||||
|
||||
v = sqliteGetVdbe(pParse);
|
||||
assert( v!=0 );
|
||||
nCol = pTab->nCol;
|
||||
recnoChng = (recnoChng!=0); /* Must be either 1 or 0 */
|
||||
|
||||
/* Test all NOT NULL constraints.
|
||||
*/
|
||||
@ -417,7 +414,7 @@ void sqliteGenerateConstraintChecks(
|
||||
break;
|
||||
}
|
||||
case OE_Ignore: {
|
||||
sqliteVdbeAddOp(v, OP_Pop, nCol+1+recnoChng, 0);
|
||||
sqliteVdbeAddOp(v, OP_Pop, nCol+1+hasTwoRecnos, 0);
|
||||
sqliteVdbeAddOp(v, OP_Goto, 0, ignoreDest);
|
||||
break;
|
||||
}
|
||||
@ -437,7 +434,7 @@ void sqliteGenerateConstraintChecks(
|
||||
|
||||
/* Test all UNIQUE constraints. Add index records as we go.
|
||||
*/
|
||||
if( recnoChng && pTab->iPKey>=0 && pTab->keyConf!=OE_Replace
|
||||
if( (recnoChng || !isUpdate) && pTab->iPKey>=0 && pTab->keyConf!=OE_Replace
|
||||
&& overrideError!=OE_Replace ){
|
||||
sqliteVdbeAddOp(v, OP_Dup, nCol, 1);
|
||||
jumpInst = sqliteVdbeAddOp(v, OP_NotExists, base, 0);
|
||||
@ -451,7 +448,7 @@ void sqliteGenerateConstraintChecks(
|
||||
break;
|
||||
}
|
||||
case OE_Ignore: {
|
||||
sqliteVdbeAddOp(v, OP_Pop, nCol+2, 0);
|
||||
sqliteVdbeAddOp(v, OP_Pop, nCol+1+hasTwoRecnos, 0);
|
||||
sqliteVdbeAddOp(v, OP_Goto, 0, ignoreDest);
|
||||
break;
|
||||
}
|
||||
@ -483,7 +480,7 @@ void sqliteGenerateConstraintChecks(
|
||||
if( overrideError!=OE_Default ){
|
||||
onError = overrideError;
|
||||
}
|
||||
sqliteVdbeAddOp(v, OP_Dup, extra+nCol+1+recnoChng, 1);
|
||||
sqliteVdbeAddOp(v, OP_Dup, extra+nCol+1+hasTwoRecnos, 1);
|
||||
jumpInst = sqliteVdbeAddOp(v, OP_IsUnique, base+iCur+1, 0);
|
||||
switch( onError ){
|
||||
case OE_Abort: {
|
||||
@ -492,14 +489,14 @@ void sqliteGenerateConstraintChecks(
|
||||
}
|
||||
case OE_Ignore: {
|
||||
assert( seenReplace==0 );
|
||||
sqliteVdbeAddOp(v, OP_Pop, nCol+extra+2+recnoChng, 0);
|
||||
sqliteVdbeAddOp(v, OP_Pop, nCol+extra+2+hasTwoRecnos, 0);
|
||||
sqliteVdbeAddOp(v, OP_Goto, 0, ignoreDest);
|
||||
break;
|
||||
}
|
||||
case OE_Replace: {
|
||||
sqliteGenerateRowDelete(v, pTab, base);
|
||||
if( isUpdate ){
|
||||
sqliteVdbeAddOp(v, OP_Dup, nCol+extra+1+recnoChng, 1);
|
||||
sqliteVdbeAddOp(v, OP_Dup, nCol+extra+1+hasTwoRecnos, 1);
|
||||
sqliteVdbeAddOp(v, OP_MoveTo, base, 0);
|
||||
}
|
||||
seenReplace = 1;
|
||||
@ -519,7 +516,7 @@ void sqliteGenerateConstraintChecks(
|
||||
** and the recno for the new entry. This routine creates the new
|
||||
** entries in all indices and in the main table.
|
||||
**
|
||||
** The arguments to this routine should be the same as the first five
|
||||
** The arguments to this routine should be the same as the first six
|
||||
** arguments to sqliteGenerateConstraintChecks.
|
||||
*/
|
||||
void sqliteCompleteInsertion(
|
||||
@ -527,7 +524,8 @@ void sqliteCompleteInsertion(
|
||||
Table *pTab, /* the table into which we are inserting */
|
||||
int base, /* Index of a read/write cursor pointing at pTab */
|
||||
char *aIdxUsed, /* Which indices are used. NULL means all are used */
|
||||
int recnoChng /* True if the record number changed */
|
||||
int recnoChng, /* True if the record number will change */
|
||||
int isUpdate /* True for UPDATE, False for INSERT */
|
||||
){
|
||||
int i;
|
||||
Vdbe *v;
|
||||
@ -543,7 +541,7 @@ void sqliteCompleteInsertion(
|
||||
}
|
||||
sqliteVdbeAddOp(v, OP_MakeRecord, pTab->nCol, 0);
|
||||
sqliteVdbeAddOp(v, OP_PutIntKey, base, 0);
|
||||
if( recnoChng ){
|
||||
if( isUpdate && recnoChng ){
|
||||
sqliteVdbeAddOp(v, OP_Pop, 1, 0);
|
||||
}
|
||||
}
|
||||
|
10
src/parse.y
10
src/parse.y
@ -14,7 +14,7 @@
|
||||
** the parser. Lemon will also generate a header file containing
|
||||
** numeric codes for all of the tokens.
|
||||
**
|
||||
** @(#) $Id: parse.y,v 1.43 2002/01/29 18:41:25 drh Exp $
|
||||
** @(#) $Id: parse.y,v 1.44 2002/01/30 16:17:24 drh Exp $
|
||||
*/
|
||||
%token_prefix TK_
|
||||
%token_type {Token}
|
||||
@ -548,10 +548,10 @@ cmd ::= DROP INDEX ids(X). {sqliteDropIndex(pParse, &X);}
|
||||
|
||||
///////////////////////////// The COPY command ///////////////////////////////
|
||||
//
|
||||
cmd ::= COPY ids(X) FROM ids(Y) USING DELIMITERS STRING(Z).
|
||||
{sqliteCopy(pParse,&X,&Y,&Z);}
|
||||
cmd ::= COPY ids(X) FROM ids(Y).
|
||||
{sqliteCopy(pParse,&X,&Y,0);}
|
||||
cmd ::= COPY onconf_u(R) ids(X) FROM ids(Y) USING DELIMITERS STRING(Z).
|
||||
{sqliteCopy(pParse,&X,&Y,&Z,R);}
|
||||
cmd ::= COPY onconf_u(R) ids(X) FROM ids(Y).
|
||||
{sqliteCopy(pParse,&X,&Y,0,R);}
|
||||
|
||||
///////////////////////////// The VACUUM command /////////////////////////////
|
||||
//
|
||||
|
@ -11,7 +11,7 @@
|
||||
*************************************************************************
|
||||
** Internal interface definitions for SQLite.
|
||||
**
|
||||
** @(#) $Id: sqliteInt.h,v 1.81 2002/01/29 23:07:02 drh Exp $
|
||||
** @(#) $Id: sqliteInt.h,v 1.82 2002/01/30 16:17:24 drh Exp $
|
||||
*/
|
||||
#include "sqlite.h"
|
||||
#include "hash.h"
|
||||
@ -527,7 +527,7 @@ void sqliteExprIfFalse(Parse*, Expr*, int);
|
||||
Table *sqliteFindTable(sqlite*,char*);
|
||||
Index *sqliteFindIndex(sqlite*,char*);
|
||||
void sqliteUnlinkAndDeleteIndex(sqlite*,Index*);
|
||||
void sqliteCopy(Parse*, Token*, Token*, Token*);
|
||||
void sqliteCopy(Parse*, Token*, Token*, Token*, int);
|
||||
void sqliteVacuum(Parse*, Token*);
|
||||
int sqliteGlobCompare(const unsigned char*,const unsigned char*);
|
||||
int sqliteLikeCompare(const unsigned char*,const unsigned char*);
|
||||
@ -550,4 +550,4 @@ int sqliteExprIsConstant(Expr*);
|
||||
void sqliteGenerateRowDelete(Vdbe*, Table*, int);
|
||||
void sqliteGenerateRowIndexDelete(Vdbe*, Table*, int, char*);
|
||||
void sqliteGenerateConstraintChecks(Parse*,Table*,int,char*,int,int,int,int);
|
||||
void sqliteCompleteInsertion(Parse*, Table*, int, char*, int);
|
||||
void sqliteCompleteInsertion(Parse*, Table*, int, char*, int, int);
|
||||
|
@ -12,7 +12,7 @@
|
||||
** This file contains C code routines that are called by the parser
|
||||
** to handle UPDATE statements.
|
||||
**
|
||||
** $Id: update.c,v 1.30 2002/01/29 23:07:02 drh Exp $
|
||||
** $Id: update.c,v 1.31 2002/01/30 16:17:24 drh Exp $
|
||||
*/
|
||||
#include "sqliteInt.h"
|
||||
|
||||
@ -253,8 +253,8 @@ void sqliteUpdate(
|
||||
|
||||
/* Do constraint checks
|
||||
*/
|
||||
sqliteGenerateConstraintChecks(pParse, pTab, base, aIdxUsed, chngRecno,
|
||||
onError, addr,1);
|
||||
sqliteGenerateConstraintChecks(pParse, pTab, base, aIdxUsed, chngRecno, 1,
|
||||
onError, addr);
|
||||
|
||||
/* Delete the old indices for the current record.
|
||||
*/
|
||||
@ -268,7 +268,7 @@ void sqliteUpdate(
|
||||
|
||||
/* Create the new index entries and the new record.
|
||||
*/
|
||||
sqliteCompleteInsertion(pParse, pTab, base, aIdxUsed, chngRecno);
|
||||
sqliteCompleteInsertion(pParse, pTab, base, aIdxUsed, chngRecno, 1);
|
||||
|
||||
/* Increment the row counter
|
||||
*/
|
||||
|
48
src/vdbe.c
48
src/vdbe.c
@ -30,7 +30,7 @@
|
||||
** But other routines are also provided to help in building up
|
||||
** a program instruction by instruction.
|
||||
**
|
||||
** $Id: vdbe.c,v 1.111 2002/01/30 00:54:56 drh Exp $
|
||||
** $Id: vdbe.c,v 1.112 2002/01/30 16:17:24 drh Exp $
|
||||
*/
|
||||
#include "sqliteInt.h"
|
||||
#include <ctype.h>
|
||||
@ -3824,8 +3824,11 @@ case OP_FileOpen: {
|
||||
** we are able to get another line, split the line apart using P3 as
|
||||
** a delimiter. There should be P1 fields. If the input line contains
|
||||
** more than P1 fields, ignore the excess. If the input line contains
|
||||
** fewer than P1 fields, assume the remaining fields contain an
|
||||
** empty strings.
|
||||
** fewer than P1 fields, assume the remaining fields contain NULLs.
|
||||
**
|
||||
** Input ends if a line consists of just "\.". A field containing only
|
||||
** "\N" is a null field. The backslash \ character can be used be used
|
||||
** to escape newlines or the delimiter.
|
||||
*/
|
||||
case OP_FileRead: {
|
||||
int n, eol, nField, i, c, nDelim;
|
||||
@ -3858,11 +3861,18 @@ case OP_FileRead: {
|
||||
eol = 1;
|
||||
p->zLine[n] = 0;
|
||||
}else{
|
||||
while( p->zLine[n] ){ n++; }
|
||||
if( n>0 && p->zLine[n-1]=='\n' ){
|
||||
n--;
|
||||
p->zLine[n] = 0;
|
||||
eol = 1;
|
||||
int c;
|
||||
while( (c = p->zLine[n])!=0 ){
|
||||
if( c=='\\' ){
|
||||
if( p->zLine[n+1]==0 ) break;
|
||||
n += 2;
|
||||
}else if( c=='\n' ){
|
||||
p->zLine[n] = 0;
|
||||
eol = 1;
|
||||
break;
|
||||
}else{
|
||||
n++;
|
||||
}
|
||||
}
|
||||
}
|
||||
}
|
||||
@ -3879,6 +3889,13 @@ case OP_FileRead: {
|
||||
for(i=1; *z!=0 && i<=nField; i++){
|
||||
int from, to;
|
||||
from = to = 0;
|
||||
if( z[0]=='\\' && z[1]=='N'
|
||||
&& (z[2]==0 || strncmp(&z[2],zDelim,nDelim)==0) ){
|
||||
if( i<=nField ) p->azField[i-1] = 0;
|
||||
z += 2 + nDelim;
|
||||
if( i<nField ) p->azField[i] = z;
|
||||
continue;
|
||||
}
|
||||
while( z[from] ){
|
||||
if( z[from]=='\\' && z[from+1]!=0 ){
|
||||
z[to++] = z[from+1];
|
||||
@ -3898,7 +3915,7 @@ case OP_FileRead: {
|
||||
}
|
||||
}
|
||||
while( i<nField ){
|
||||
p->azField[i++] = "";
|
||||
p->azField[i++] = 0;
|
||||
}
|
||||
break;
|
||||
|
||||
@ -3923,11 +3940,16 @@ case OP_FileColumn: {
|
||||
}else{
|
||||
z = 0;
|
||||
}
|
||||
if( z==0 ) z = "";
|
||||
p->tos++;
|
||||
aStack[p->tos].n = strlen(z) + 1;
|
||||
zStack[p->tos] = z;
|
||||
aStack[p->tos].flags = STK_Str;
|
||||
if( z ){
|
||||
aStack[p->tos].n = strlen(z) + 1;
|
||||
zStack[p->tos] = z;
|
||||
aStack[p->tos].flags = STK_Str;
|
||||
}else{
|
||||
aStack[p->tos].n = 0;
|
||||
zStack[p->tos] = 0;
|
||||
aStack[p->tos].flags = STK_Null;
|
||||
}
|
||||
break;
|
||||
}
|
||||
|
||||
|
@ -13,7 +13,7 @@
|
||||
# This file implements tests for the conflict resolution extension
|
||||
# to SQLite.
|
||||
#
|
||||
# $Id: conflict.test,v 1.2 2002/01/30 04:32:01 drh Exp $
|
||||
# $Id: conflict.test,v 1.3 2002/01/30 16:17:25 drh Exp $
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
@ -162,7 +162,7 @@ do_test conflict-2.2 {
|
||||
}
|
||||
} {1 {constraint failed}}
|
||||
do_test conflict-2.3 {
|
||||
catchsql {
|
||||
catchsql {
|
||||
INSERT ON CONFLICT IGNORE INTO t1 VALUES(1,2,4);
|
||||
SELECT c FROM t1 ORDER BY c;
|
||||
}
|
||||
|
@ -11,7 +11,7 @@
|
||||
# This file implements regression tests for SQLite library. The
|
||||
# focus of this file is testing the COPY statement.
|
||||
#
|
||||
# $Id: copy.test,v 1.6 2001/09/16 00:13:28 drh Exp $
|
||||
# $Id: copy.test,v 1.7 2002/01/30 16:17:25 drh Exp $
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
@ -123,6 +123,7 @@ do_test copy-2.1 {
|
||||
execsql {COPY test2 FROM 'data21.txt'}
|
||||
execsql {SELECT x from test2}
|
||||
} $x
|
||||
file delete -force data21.txt
|
||||
|
||||
# Test the escape character mechanism
|
||||
#
|
||||
@ -137,9 +138,79 @@ do_test copy-3.1 {
|
||||
SELECT * FROM t1 ORDER BY a;
|
||||
}
|
||||
} {hello {world 2} {hello world} 1}
|
||||
do_test copy-3.2 {
|
||||
set fd [open data6.txt w]
|
||||
puts $fd "1\thello\\\nworld"
|
||||
puts $fd "2\thello world"
|
||||
close $fd
|
||||
execsql {
|
||||
DELETE FROM t1;
|
||||
COPY t1 FROM 'data6.txt';
|
||||
SELECT * FROM t1 ORDER BY a;
|
||||
}
|
||||
} {1 {hello
|
||||
world} 2 {hello world}}
|
||||
|
||||
# Test the embedded NULL logic.
|
||||
#
|
||||
do_test copy-4.1 {
|
||||
set fd [open data6.txt w]
|
||||
puts $fd "1\t\\N"
|
||||
puts $fd "\\N\thello world"
|
||||
close $fd
|
||||
execsql {
|
||||
DELETE FROM t1;
|
||||
COPY t1 FROM 'data6.txt';
|
||||
SELECT * FROM t1 WHERE a IS NULL;
|
||||
}
|
||||
} {{} {hello world}}
|
||||
do_test copy-4.2 {
|
||||
execsql {
|
||||
SELECT * FROM t1 WHERE b IS NULL;
|
||||
}
|
||||
} {1 {}}
|
||||
|
||||
# Test the conflict resolution logic for COPY
|
||||
#
|
||||
do_test copy-5.1 {
|
||||
execsql {
|
||||
DROP TABLE t1;
|
||||
CREATE TABLE t1(a INTEGER PRIMARY KEY, b UNIQUE, c);
|
||||
COPY t1 FROM 'data5.txt' USING DELIMITERS '|';
|
||||
SELECT * FROM t1;
|
||||
}
|
||||
} {11 22 33 22 33 11}
|
||||
do_test copy-5.2 {
|
||||
set fd [open data6.txt w]
|
||||
puts $fd "33|22|44"
|
||||
close $fd
|
||||
catchsql {
|
||||
COPY t1 FROM 'data6.txt' USING DELIMITERS '|';
|
||||
SELECT * FROM t1;
|
||||
}
|
||||
} {1 {constraint failed}}
|
||||
do_test copy-5.3 {
|
||||
set fd [open data6.txt w]
|
||||
puts $fd "33|22|44"
|
||||
close $fd
|
||||
catchsql {
|
||||
COPY ON CONFLICT IGNORE t1 FROM 'data6.txt' USING DELIMITERS '|';
|
||||
SELECT * FROM t1;
|
||||
}
|
||||
} {0 {11 22 33 22 33 11}}
|
||||
do_test copy-5.4 {
|
||||
set fd [open data6.txt w]
|
||||
puts $fd "33|22|44"
|
||||
close $fd
|
||||
catchsql {
|
||||
COPY ON CONFLICT REPLACE t1 FROM 'data6.txt' USING DELIMITERS '|';
|
||||
SELECT * FROM t1;
|
||||
}
|
||||
} {0 {22 33 11 33 22 44}}
|
||||
|
||||
|
||||
# Cleanup
|
||||
#
|
||||
file delete -force data1.txt data2.txt data3.txt data4.txt data5.txt data21.txt
|
||||
file delete -force data1.txt data2.txt data3.txt data4.txt data5.txt data6.txt
|
||||
|
||||
finish_test
|
||||
|
@ -17,6 +17,15 @@ proc chng {date desc} {
|
||||
puts "<DD><P><UL>$desc</UL></P></DD>"
|
||||
}
|
||||
|
||||
chng {2002 Jan 30 (2.3.0 beta)} {
|
||||
<li>Added the ability to resolve constraint conflicts is ways other than
|
||||
an abort and rollback. See the documentation on the "ON CONFLICT"
|
||||
clause for details.</li>
|
||||
<li>NOT NULL constraints are honored.</li>
|
||||
<li>The COPY command puts NULLs in columns whose data is '\N'.</li>
|
||||
<li>In the COPY command, backslash can now be used to escape a newline.</li>
|
||||
}
|
||||
|
||||
chng {2002 Jan 28 (2.2.5)} {
|
||||
<li>Important bug fix: the IN operator was not working if either the
|
||||
left-hand or right-hand side was derived from an INTEGER PRIMARY KEY.</li>
|
||||
|
191
www/conflict.tcl
Normal file
191
www/conflict.tcl
Normal file
@ -0,0 +1,191 @@
|
||||
#
|
||||
# Run this Tcl script to generate the constraint.html file.
|
||||
#
|
||||
set rcsid {$Id: conflict.tcl,v 1.1 2002/01/30 16:17:25 drh Exp $ }
|
||||
|
||||
puts {<html>
|
||||
<head>
|
||||
<title>Constraint Conflict Resolution in SQLite</title>
|
||||
</head>
|
||||
<body bgcolor=white>
|
||||
<h1 align=center>
|
||||
Constraint Conflict Resolution in SQLite
|
||||
</h1>}
|
||||
puts "<p align=center>
|
||||
(This page was last modified on [lrange $rcsid 3 4] UTC)
|
||||
</p>"
|
||||
|
||||
puts {
|
||||
<h2>Introduction</h2>
|
||||
|
||||
<p>
|
||||
In most SQL databases, if you have a UNIQUE constraint on
|
||||
a table and you try to do an UPDATE or INSERT that violates
|
||||
that constraint, the database will aborts the operation in
|
||||
progress and rolls back the current transaction.
|
||||
This is the default behavior of SQLite.
|
||||
Beginning with version 2.3.0, though, SQLite allows you to
|
||||
define alternative ways for dealing with constraint violations.
|
||||
This article describes those alternatives and how to use them.
|
||||
</p>
|
||||
|
||||
<h2>Conflict Resolution Algorithms</h2>
|
||||
|
||||
<p>
|
||||
The default conflict resolution algorithm is to abort the
|
||||
operation in progress, rollback all changes, and cancel the
|
||||
current transaction. Call this algorithm "ABORT". Abort
|
||||
is the standard way of dealing with a constraint error
|
||||
in most SQL databases.
|
||||
</p>
|
||||
|
||||
<p>
|
||||
Sometimes ABORT is not the most helpful way of dealing
|
||||
with constraint violations. Suppose, for example, you are
|
||||
inserting 1000 records into a database, all within a single
|
||||
transaction, but one of those records is malformed and causes
|
||||
a constraint error. With the default ABORT behavior, none
|
||||
of the 1000 records gets inserted. But sometimes it is
|
||||
desirable to just omit the single malformed insert and
|
||||
finish the other 999.
|
||||
</p>
|
||||
|
||||
<p>
|
||||
SQLite defines two addition conflict resolution algorithms
|
||||
called "IGNORE" and "REPLACE".
|
||||
If you are trying to do multiple INSERTs or UPDATEs when a constraint
|
||||
fails for a single row and the conflict behavior is IGNORE, then
|
||||
that row remains uninserted or unmodified. But the overall operation
|
||||
is not aborted and no rollback occurs. If a constraint
|
||||
fails and the behavior is REPLACE, then SQLite tries to
|
||||
delete other rows in the table in order to eliminate the
|
||||
constraint problem. Again, the overall operation continues
|
||||
and no rollback occurs.
|
||||
</p>
|
||||
|
||||
<p>
|
||||
The default conflict resolution algorithm is always ABORT
|
||||
but you can specify an alternative algorithm using special
|
||||
(non-standard) syntax on the INSERT and UPDATE commands.
|
||||
You can add the clause "ON CONFLICT <algorithm>" immediately
|
||||
after the "INSERT" or "UPDATE" keywords to specify the
|
||||
conflict resolution algorithm to use for that one operation.
|
||||
(Substitute "ABORT", "IGNORE", or "REPLACE" for <algorithm>,
|
||||
of course.)
|
||||
</p>
|
||||
|
||||
Consider this example:
|
||||
|
||||
<blockquote><pre>
|
||||
BEGIN;
|
||||
CREATE TABLE t1(
|
||||
a INTEGER,
|
||||
b INTEGER,
|
||||
c INTEGER,
|
||||
UNIQUE(a,b)
|
||||
);
|
||||
INSERT INTO a VALUES(1,2,3);
|
||||
COMMIT;
|
||||
|
||||
BEGIN;
|
||||
INSERT INTO a VALUES(2,3,4);
|
||||
INSERT INTO a VALUES(1,2,5);
|
||||
</pre></blockquote>
|
||||
|
||||
<p>
|
||||
In the last instruction, the UNIQUE constraint fails
|
||||
and the entire transaction is rolled back. The database
|
||||
now contains a single entry: {1,2,3}.
|
||||
</p>
|
||||
|
||||
<blockquote><pre>
|
||||
BEGIN;
|
||||
INSERT ON CONFLICT IGNORE INTO a VALUES(2,3,4);
|
||||
INSERT ON CONFLICT IGNORE INTO a VALUES(1,2,5);
|
||||
COMMIT;
|
||||
</pre></blockquote>
|
||||
|
||||
<p>This time the "ON CONFLICT IGNORE" clause tells SQLite to use
|
||||
IGNORE semantics when a constraint fails. The second
|
||||
INSERT statement fails, but the database is
|
||||
not rolled back and there is no failure. The database
|
||||
now contains two rows: {1,2,3} and {2,3,4}.</p>
|
||||
|
||||
<blockquote><pre>
|
||||
BEGIN;
|
||||
INSERT ON CONFLICT REPLACE INTO a VALUES(1,2,5);
|
||||
COMMIT;
|
||||
</pre></blockquote>
|
||||
|
||||
<p>Here the "ON CONFLICT REPLACE" clause tells SQLite to use REPLACE
|
||||
semantics. The {1,2,3} is deleted when the {1,2,5} row
|
||||
is inserted in order to satisfy the constraint. After
|
||||
the above, the database contains {1,2,5} and {2,3,4}.</p>
|
||||
|
||||
<h2>A Syntactic Shortcut</h2>
|
||||
|
||||
<p>On an INSERT, the "ON CONFLICT" keywords may be omitted for brevity.
|
||||
So you can say</p>
|
||||
|
||||
<blockquote><pre>
|
||||
INSERT IGNORE INTO a VALUES(1,2,5);
|
||||
</pre></blockquote>
|
||||
|
||||
<p>Instead of the more wordy:</p>
|
||||
|
||||
<blockquote><pre>
|
||||
INSERT ON CONFLICT IGNORE INTO a VALUES(1,2,5);
|
||||
</pre></blockquote>
|
||||
|
||||
<p>Unfortunately, you cannot do this with an UPDATE.</p>
|
||||
|
||||
<h2>Changing The Default Conflict Resolution Algorithm</h2>
|
||||
|
||||
<p>You can change the default conflict resolution algorithm
|
||||
on a constraint-by-constraint basis using special (non-standard)
|
||||
syntax in CREATE TABLE and CREATE INDEX statements. The
|
||||
same "ON CONFLICT" clause that appears in INSERT and UPDATE
|
||||
statements is used but the clause is attached to the constraint
|
||||
in the CREATE TABLE statement. Like this:
|
||||
|
||||
<blockquote><pre>
|
||||
CREATE TABLE t1 (
|
||||
a INTEGER,
|
||||
b INTEGER,
|
||||
c INTEGER,
|
||||
UNIQUE(a,b) ON CONFLICT REPLACE
|
||||
);
|
||||
</pre></blockquote>
|
||||
|
||||
<p>The ON CONFLICT clause in the above table definition says that
|
||||
the default conflict resolution algorithm is REPLACE instead
|
||||
of ABORT. REPLACE will always be used unless you override
|
||||
this by saying "INSERT IGNORE" or "INSERT ABORT".</p>
|
||||
|
||||
<p>The ON CONFLICT clause can also appear on a NOT NULL constraint,
|
||||
a PRIMARY KEY constraint, and a CHECK constraint.
|
||||
(Note, however, that CHECK constraints are not currently enforced
|
||||
so the ON CONFLICT clause has no effect there.)</p>
|
||||
|
||||
<p>A NOT NULL constraint will normally ABORT if you try to insert
|
||||
a NULL. But if you substitute the REPLACE algorithm, it tries to insert
|
||||
the default value in place of the NULL. If there is no default value,
|
||||
then REPLACE is the same as ABORT for NOT NULL constraints.
|
||||
With the IGNORE algorithm on a NOT NULL, the INSERT or UPDATE
|
||||
is suppressed if the value is NULL.</p>
|
||||
|
||||
<h2>Portability</h2>
|
||||
|
||||
<p>The ON CONFLICT syntax is not standard SQL and will not
|
||||
(as far as is known) work on any other database product. Furthermore,
|
||||
the syntax might change in future versions of SQLite. So use it
|
||||
with appropriate discretion.</p>
|
||||
}
|
||||
|
||||
puts {
|
||||
<p><hr /></p>
|
||||
<p><a href="index.html"><img src="/goback.jpg" border=0 />
|
||||
Back to the SQLite Home Page</a>
|
||||
</p>
|
||||
|
||||
</body></html>}
|
@ -1,7 +1,7 @@
|
||||
#
|
||||
# Run this Tcl script to generate the formatchng.html file.
|
||||
#
|
||||
set rcsid {$Id: formatchng.tcl,v 1.1 2001/12/22 19:27:41 drh Exp $ }
|
||||
set rcsid {$Id: formatchng.tcl,v 1.2 2002/01/30 16:17:25 drh Exp $ }
|
||||
|
||||
puts {<html>
|
||||
<head>
|
||||
@ -81,6 +81,16 @@ occurred since version 1.0.0:
|
||||
and version 2.2.x database files will be identical and completely
|
||||
interchangeable.</p>
|
||||
</tr>
|
||||
<tr>
|
||||
<td valign="top">2.2.5 to 2.3.0</td>
|
||||
<td valign="top">2002-Jan-30</td>
|
||||
<td>Beginning with version 2.3.0, SQLite supports some additional syntax
|
||||
(the "ON CONFLICT" clause) in the CREATE TABLE and CREATE INDEX statements
|
||||
that are stored in the SQLITE_MASTER table. If you create a database that
|
||||
contains this new syntax, then try to read that database using version 2.2.5
|
||||
or earlier, the parser will not understand the new syntax and you will get
|
||||
an error. Otherwise, databases for 2.2.x and 2.3.x are interchangeable.</p>
|
||||
</tr>
|
||||
</table>
|
||||
</blockquote>
|
||||
|
||||
|
112
www/lang.tcl
112
www/lang.tcl
@ -1,7 +1,7 @@
|
||||
#
|
||||
# Run this Tcl script to generate the sqlite.html file.
|
||||
#
|
||||
set rcsid {$Id: lang.tcl,v 1.18 2001/12/22 19:27:41 drh Exp $}
|
||||
set rcsid {$Id: lang.tcl,v 1.19 2002/01/30 16:17:25 drh Exp $}
|
||||
|
||||
puts {<html>
|
||||
<head>
|
||||
@ -31,7 +31,7 @@ by SQLite. Many low-level productions are omitted. For detailed information
|
||||
on the language that SQLite understands, refer to the source code.</p>
|
||||
|
||||
|
||||
<p>SQLite implements the follow SQL commands:</p>
|
||||
<p>SQLite implements the follow syntax:</p>
|
||||
<p><ul>
|
||||
}
|
||||
|
||||
@ -50,6 +50,7 @@ foreach {section} [lsort -index 0 -dictionary {
|
||||
{expression expr}
|
||||
{{BEGIN TRANSACTION} transaction}
|
||||
{PRAGMA pragma}
|
||||
{{ON CONFLICT clause} conflict}
|
||||
}] {
|
||||
puts "<li><a href=\"#[lindex $section 1]\">[lindex $section 0]</a></li>"
|
||||
}
|
||||
@ -140,12 +141,47 @@ a alias for COMMIT.
|
||||
</p>
|
||||
}
|
||||
|
||||
Section {ON CONFLICT clause} conflict
|
||||
|
||||
Syntax {conflict-clause} {
|
||||
ON CONFLICT <algorithm>
|
||||
} {algorithm} {
|
||||
ABORT | IGNORE | REPLACE
|
||||
}
|
||||
|
||||
puts {
|
||||
<p>The ON CONFLICT clause is not a separate SQL command. It is a
|
||||
non-standard clause that can appear in many other SQL commands.
|
||||
It is given its own section in this document because it is not
|
||||
part of standard SQL and therefore might not be familiar.</p>
|
||||
|
||||
<p>The ON CONFLICT clause specifies an algorithm used to resolve
|
||||
constraint conflicts. The default algorithm is ABORT. When the
|
||||
ABORT algorithm is in use, any constraint violation causes the
|
||||
command to abort and the current transaction to be rolled back.
|
||||
This is the only behavior exhibited by most SQL engines. But
|
||||
SQLite allows two alternative behaviors: IGNORE and REPLACE.
|
||||
The IGNORE algorithm means that when a constraint violation occurs
|
||||
on a COPY, INSERT or UPDATE, the particular row that caused the constraint
|
||||
violation is not inserted or changed, but other rows effected by the
|
||||
COPY, INSERT, or UPDATE are insert or changed as usual.
|
||||
The command is not aborted and no rollback occurs.
|
||||
If the algorithm is REPLACE, then SQLite tries to
|
||||
delete preexisting rows from the table to remove the constraint
|
||||
violation before inserting or changing the row.</p>
|
||||
|
||||
<p>For additional information, see
|
||||
<a href="conflict.html">conflict.html</a>.</p>
|
||||
}
|
||||
|
||||
Section COPY copy
|
||||
|
||||
Syntax {sql-statement} {
|
||||
COPY <table-name> FROM <filename>
|
||||
COPY [ <conflict-clause> ] <table-name> FROM <filename>
|
||||
[ USING DELIMITERS <delim> ]
|
||||
}
|
||||
|
||||
|
||||
puts {
|
||||
<p>The COPY command is an extension used to load large amounts of
|
||||
data into a table. It is modeled after a similar command found
|
||||
@ -163,7 +199,16 @@ the <b>STDIN</b> to read data from standard input.<p>
|
||||
in the table. Columns are separated by tabs. If a tab occurs as
|
||||
data within a column, then that tab is preceded by a baskslash "\"
|
||||
character. A baskslash in the data appears as two backslashes in
|
||||
a row.</p>
|
||||
a row. The optional USING DELIMITERS clause can specify a delimiter
|
||||
other than tab.</p>
|
||||
|
||||
<p>If a column consists of the character "\N", that column is filled
|
||||
with the value NULL.</p>
|
||||
|
||||
<p>The optional conflict-clause allows the specification of an alternative
|
||||
constraint conflict resolution algorithm to use for this one command.
|
||||
See the section titled
|
||||
<a href="#conflict">ON CONFLICT</a> for additional information.</p>
|
||||
|
||||
<p>When the input data source is STDIN, the input can be terminated
|
||||
by a line that contains only a baskslash and a dot:}
|
||||
@ -174,10 +219,12 @@ Section {CREATE INDEX} createindex
|
||||
Syntax {sql-statement} {
|
||||
CREATE [UNIQUE] INDEX <index-name>
|
||||
ON <table-name> ( <column-name> [, <column-name>]* )
|
||||
[ <conflict-clause> ]
|
||||
} {column-name} {
|
||||
<name> [ ASC | DESC ]
|
||||
}
|
||||
|
||||
|
||||
puts {
|
||||
<p>The CREATE INDEX command consists of the keywords "CREATE INDEX" followed
|
||||
by the name of the new index, the keyword "ON", the name of a previously
|
||||
@ -194,6 +241,16 @@ attached to a single table, nor on the number of columns in an index.</p>
|
||||
index entries are not allowed. Any attempt to insert a duplicate entry
|
||||
will result in a rollback and an error message.</p>
|
||||
|
||||
<p>The optional conflict-clause allows the specification of al alternative
|
||||
default constraint conflict resolution algorithm for this index.
|
||||
This only makes sense if the UNIQUE keyword is used since otherwise
|
||||
there are not constraints on the index. The default algorithm is
|
||||
ABORT. If a COPY, INSERT, or UPDATE statement specifies a particular
|
||||
conflict resolution algorithm, that algorithm is used in place of
|
||||
the default algorithm specified here.
|
||||
See the section titled
|
||||
<a href="#conflict">ON CONFLICT</a> for additional information.</p>
|
||||
|
||||
<p>The exact text
|
||||
of each CREATE INDEX statement is stored in the <b>sqlite_master</b>
|
||||
table. Everytime the database is opened, all CREATE INDEX statements
|
||||
@ -216,15 +273,15 @@ CREATE [TEMP | TEMPORARY] TABLE <table-name> (
|
||||
<typename> ( <number> ) |
|
||||
<typename> ( <number> , <number> )
|
||||
} {column-constraint} {
|
||||
NOT NULL |
|
||||
PRIMARY KEY [<sort-order>] |
|
||||
UNIQUE |
|
||||
CHECK ( <expr> ) |
|
||||
NOT NULL [ <conflict-clause> ] |
|
||||
PRIMARY KEY [<sort-order>] [ <conflict-clause> ] |
|
||||
UNIQUE [ <conflict-clause> ] |
|
||||
CHECK ( <expr> ) [ <conflict-clause> ] |
|
||||
DEFAULT <value>
|
||||
} {constraint} {
|
||||
PRIMARY KEY ( <name> [, <name>]* ) |
|
||||
UNIQUE ( <name> [, <name>]* ) |
|
||||
CHECK ( <expr> )
|
||||
PRIMARY KEY ( <name> [, <name>]* ) [ <conflict-clause> ]|
|
||||
UNIQUE ( <name> [, <name>]* ) [ <conflict-clause> ] |
|
||||
CHECK ( <expr> ) [ <conflict-clause> ]
|
||||
}
|
||||
|
||||
puts {
|
||||
@ -265,6 +322,17 @@ the database is closed. Any indices created on a temporary table
|
||||
are also temporary. Temporary tables and indices are stored in a
|
||||
separate file distinct from the main database file.</p>
|
||||
|
||||
<p>The optional conflict-clause following each constraint
|
||||
allows the specification of an alternative default
|
||||
constraint conflict resolution algorithm for that constraint.
|
||||
The default is abort ABORT. Different constraints within the same
|
||||
table may have different default conflict resolution algorithms.
|
||||
If an COPY, INSERT, or UPDATE command specifies a different conflict
|
||||
resolution algorithm, then that algorithm is used in place of the
|
||||
default algorithm specified in the CREATE TABLE statement.
|
||||
See the section titled
|
||||
<a href="#conflict">ON CONFLICT</a> for additional information.</p>
|
||||
|
||||
<p>There are no arbitrary limits on the number
|
||||
of columns or on the number of constraints in a table.
|
||||
The total amount of data in a single row is limited to about
|
||||
@ -363,7 +431,7 @@ LIKE | GLOB | NOT LIKE | NOT GLOB
|
||||
}
|
||||
|
||||
puts {
|
||||
<p>This section is different from the others. Every other section of
|
||||
<p>This section is different from the others. Most other sections of
|
||||
this document talks about a particular SQL command. This section does
|
||||
not talk about a standalone command but about "expressions" which are
|
||||
subcomponent of most other commands.</p>
|
||||
@ -490,8 +558,8 @@ The "<b>count(*)</b>" syntax is supported but
|
||||
Section INSERT insert
|
||||
|
||||
Syntax {sql-statement} {
|
||||
INSERT INTO <table-name> [( <column-list> )] VALUES ( <value-list> ) |
|
||||
INSERT INTO <table-name> [( <column-list> )] <select-statement>
|
||||
INSERT [ <conflict-clause> ] INTO <table-name> [( <column-list> )] VALUES ( <value-list> ) |
|
||||
INSERT [ <conflict-clause> ] INTO <table-name> [( <column-list> )] <select-statement>
|
||||
}
|
||||
|
||||
puts {
|
||||
@ -513,6 +581,11 @@ name in the column list. A new entry is made in the table
|
||||
for every row of the SELECT result. The SELECT may be simple
|
||||
or compound. If the SELECT statement has an ORDER BY clause,
|
||||
the ORDER BY is ignored.</p>
|
||||
|
||||
<p>The optional conflict-clause allows the specification of an alternative
|
||||
constraint conflict resolution algorithm to use during this one command.
|
||||
See the section titled
|
||||
<a href="#conflict">ON CONFLICT</a> for additional information.</p>
|
||||
}
|
||||
|
||||
Section SELECT select
|
||||
@ -597,7 +670,9 @@ are connected into a compound, they group from left to right.</p>
|
||||
Section UPDATE update
|
||||
|
||||
Syntax {sql-statement} {
|
||||
UPDATE <table-name> SET <assignment> [, <assignment>] [WHERE <expression>]
|
||||
UPDATE [ <conflict-clause> ] <table-name>
|
||||
SET <assignment> [, <assignment>]
|
||||
[WHERE <expression>]
|
||||
} {assignment} {
|
||||
<column-name> = <expression>
|
||||
}
|
||||
@ -608,7 +683,12 @@ selected rows of a table. Each assignment in an UPDATE specifies
|
||||
a column name to the left of the equals sign and an arbitrary expression
|
||||
to the right. The expressions may use the values of other columns.
|
||||
All expressions are evaluated before any assignments are made.
|
||||
A WHERE clause can be used to restrict which rows are updated.
|
||||
A WHERE clause can be used to restrict which rows are updated.</p>
|
||||
|
||||
<p>The optional conflict-clause allows the specification of an alternative
|
||||
constraint conflict resolution algorithm to use during this one command.
|
||||
See the section titled
|
||||
<a href="#conflict">ON CONFLICT</a> for additional information.</p>
|
||||
}
|
||||
|
||||
Section VACUUM vacuum
|
||||
|
Loading…
Reference in New Issue
Block a user