SQLite

Check-in [442d8d8bfe]
Login

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

Overview
Comment:Fix minor problems with foreign key constraints where the parent table is the same as the child table.
Downloads: Tarball | ZIP archive
Timelines: family | ancestors | descendants | both | trunk
Files: files | file ages | folders
SHA1: 442d8d8bfe443797482354ba8766d97d3d6acaae
User & Date: dan 2011-06-10 16:33:25.121
Context
2011-06-10
18:33
When updating a field that requires foreign key constraints be checked, ensure that the indexes and tables are consistent when the FK logic is run. Otherwise, it may detect the inconsistency and report database corruption. (check-in: 2b3d9996a8 user: dan tags: trunk)
16:33
Fix minor problems with foreign key constraints where the parent table is the same as the child table. (check-in: 442d8d8bfe user: dan tags: trunk)
2011-06-09
17:53
Fix a line in pcache1.c where a global data structure is accessed without using the GLOBAL() macro. This causes a subtle malfunction on test systems that use SQLITE_OMIT_WSD. (check-in: b11b2e1f8c user: dan tags: trunk)
Changes
Unified Diff Ignore Whitespace Patch
Changes to src/fkey.c.
382
383
384
385
386
387
388
389






390
391
392
393
394





395

396
397
398
399
400
401
402
      for(i=0; i<nCol; i++){
        sqlite3VdbeAddOp2(v, OP_Copy, aiCol[i]+1+regData, regTemp+i);
      }
  
      /* If the parent table is the same as the child table, and we are about
      ** to increment the constraint-counter (i.e. this is an INSERT operation),
      ** then check if the row being inserted matches itself. If so, do not
      ** increment the constraint-counter.  */






      if( pTab==pFKey->pFrom && nIncr==1 ){
        int iJump = sqlite3VdbeCurrentAddr(v) + nCol + 1;
        for(i=0; i<nCol; i++){
          int iChild = aiCol[i]+1+regData;
          int iParent = pIdx->aiColumn[i]+1+regData;





          sqlite3VdbeAddOp3(v, OP_Ne, iChild, iJump, iParent);

        }
        sqlite3VdbeAddOp2(v, OP_Goto, 0, iOk);
      }
  
      sqlite3VdbeAddOp3(v, OP_MakeRecord, regTemp, nCol, regRec);
      sqlite3VdbeChangeP4(v, -1, sqlite3IndexAffinityStr(v,pIdx), P4_TRANSIENT);
      sqlite3VdbeAddOp4Int(v, OP_Found, iCur, iOk, regRec, 0);







|
>
>
>
>
>
>





>
>
>
>
>

>







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
409
410
411
412
413
414
      for(i=0; i<nCol; i++){
        sqlite3VdbeAddOp2(v, OP_Copy, aiCol[i]+1+regData, regTemp+i);
      }
  
      /* If the parent table is the same as the child table, and we are about
      ** to increment the constraint-counter (i.e. this is an INSERT operation),
      ** then check if the row being inserted matches itself. If so, do not
      ** increment the constraint-counter. 
      **
      ** If any of the parent-key values are NULL, then the row cannot match 
      ** itself. So set JUMPIFNULL to make sure we do the OP_Found if any
      ** of the parent-key values are NULL (at this point it is known that
      ** none of the child key values are).
      */
      if( pTab==pFKey->pFrom && nIncr==1 ){
        int iJump = sqlite3VdbeCurrentAddr(v) + nCol + 1;
        for(i=0; i<nCol; i++){
          int iChild = aiCol[i]+1+regData;
          int iParent = pIdx->aiColumn[i]+1+regData;
          assert( aiCol[i]!=pTab->iPKey );
          if( pIdx->aiColumn[i]==pTab->iPKey ){
            /* The parent key is a composite key that includes the IPK column */
            iParent = regData;
          }
          sqlite3VdbeAddOp3(v, OP_Ne, iChild, iJump, iParent);
          sqlite3VdbeChangeP5(v, SQLITE_JUMPIFNULL);
        }
        sqlite3VdbeAddOp2(v, OP_Goto, 0, iOk);
      }
  
      sqlite3VdbeAddOp3(v, OP_MakeRecord, regTemp, nCol, regRec);
      sqlite3VdbeChangeP4(v, -1, sqlite3IndexAffinityStr(v,pIdx), P4_TRANSIENT);
      sqlite3VdbeAddOp4Int(v, OP_Found, iCur, iOk, regRec, 0);
Changes to test/fkey3.test.
16
17
18
19
20
21
22


23
24
25
26
27
28
29
set testdir [file dirname $argv0]
source $testdir/tester.tcl

ifcapable {!foreignkey||!trigger} {
  finish_test
  return
}



# Create a table and some data to work with.
#
do_test fkey3-1.1 {
  execsql {
    PRAGMA foreign_keys=ON;
    CREATE TABLE t1(x INTEGER PRIMARY KEY);







>
>







16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
set testdir [file dirname $argv0]
source $testdir/tester.tcl

ifcapable {!foreignkey||!trigger} {
  finish_test
  return
}

set testprefix fkey3

# Create a table and some data to work with.
#
do_test fkey3-1.1 {
  execsql {
    PRAGMA foreign_keys=ON;
    CREATE TABLE t1(x INTEGER PRIMARY KEY);
73
74
75
76
77
78
79











































































80
    INSERT INTO t2 VALUES(100);
    INSERT INTO t2 VALUES(101);
    SELECT 1, x FROM t1;
    SELECT 2, y FROM t2;
  }
} {1 100 1 101 2 100 2 101}












































































finish_test







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

75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
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
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
    INSERT INTO t2 VALUES(100);
    INSERT INTO t2 VALUES(101);
    SELECT 1, x FROM t1;
    SELECT 2, y FROM t2;
  }
} {1 100 1 101 2 100 2 101}


#-------------------------------------------------------------------------
# The following tests - fkey-3.* - test some edge cases to do with 
# inserting rows into tables that have foreign keys where the parent
# table is the same as the child table. Especially cases where the
# new row being inserted matches itself.
#
do_execsql_test 3.1.1 {
  CREATE TABLE t3(a, b, c, d, 
    UNIQUE(a, b),
    FOREIGN KEY(c, d) REFERENCES t3(a, b)
  );
  INSERT INTO t3 VALUES(1, 2, 1, 2);
} {}
do_catchsql_test 3.1.2 {
  INSERT INTO t3 VALUES(NULL, 2, 5, 2);
} {1 {foreign key constraint failed}}
do_catchsql_test 3.1.3 {
  INSERT INTO t3 VALUES(NULL, 3, 5, 2);
} {1 {foreign key constraint failed}}

do_execsql_test 3.2.1 {
  CREATE TABLE t4(a UNIQUE, b REFERENCES t4(a));
}
do_catchsql_test 3.2.2 {
  INSERT INTO t4 VALUES(NULL, 1);
} {1 {foreign key constraint failed}}

do_execsql_test 3.3.1 {
  CREATE TABLE t5(a INTEGER PRIMARY KEY, b REFERENCES t5(a));
  INSERT INTO t5 VALUES(NULL, 1);
} {}
do_catchsql_test 3.3.2 {
  INSERT INTO t5 VALUES(NULL, 3);
} {1 {foreign key constraint failed}}

do_execsql_test 3.4.1 {
  CREATE TABLE t6(a INTEGER PRIMARY KEY, b, c, d,
    FOREIGN KEY(c, d) REFERENCES t6(a, b)
  );
  CREATE UNIQUE INDEX t6i ON t6(b, a);
}
do_execsql_test 3.4.2  { INSERT INTO t6 VALUES(NULL, 'a', 1, 'a'); } {}
do_execsql_test 3.4.3  { INSERT INTO t6 VALUES(2, 'a', 2, 'a');    } {}
do_execsql_test 3.4.4  { INSERT INTO t6 VALUES(NULL, 'a', 1, 'a'); } {}
do_execsql_test 3.4.5  { INSERT INTO t6 VALUES(5, 'a', 2, 'a'); } {}
do_catchsql_test 3.4.6 { 
  INSERT INTO t6 VALUES(NULL, 'a', 65, 'a');    
} {1 {foreign key constraint failed}}

do_execsql_test 3.4.7 {
  INSERT INTO t6 VALUES(100, 'one', 100, 'one');
  DELETE FROM t6 WHERE a = 100;
}
do_execsql_test 3.4.8 {
  INSERT INTO t6 VALUES(100, 'one', 100, 'one');
  UPDATE t6 SET c = 1, d = 'a' WHERE a = 100;
  DELETE FROM t6 WHERE a = 100;
}

do_execsql_test 3.5.1 {
  CREATE TABLE t7(a, b, c, d INTEGER PRIMARY KEY,
    FOREIGN KEY(c, d) REFERENCES t7(a, b)
  );
  CREATE UNIQUE INDEX t7i ON t7(a, b);
}
do_execsql_test 3.5.2  { INSERT INTO t7 VALUES('x', 1, 'x', NULL) } {}
do_execsql_test 3.5.3  { INSERT INTO t7 VALUES('x', 2, 'x', 2) } {}
do_catchsql_test 3.5.4  { 
  INSERT INTO t7 VALUES('x', 450, 'x', NULL);
} {1 {foreign key constraint failed}}
do_catchsql_test 3.5.5  { 
  INSERT INTO t7 VALUES('x', 450, 'x', 451);
} {1 {foreign key constraint failed}}

finish_test