diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index ea840fb846..013dc7c4da 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -735,7 +735,7 @@ CREATE TABLE t1 ( - A table can contain more than one foreign key constraint. This is + A table can have more than one foreign key constraint. This is used to implement many-to-many relationships between tables. Say you have tables about products and orders, but now you want to allow one order to contain possibly many products (which the @@ -827,11 +827,12 @@ CREATE TABLE order_items ( row(s) referencing it should be automatically deleted as well. There are two other options: SET NULL and SET DEFAULT. - These cause the referencing columns to be set to nulls or default + These cause the referencing column(s) in the referencing row(s) + to be set to nulls or their default values, respectively, when the referenced row is deleted. Note that these do not excuse you from observing any constraints. For example, if an action specifies SET DEFAULT - but the default value would not satisfy the foreign key, the + but the default value would not satisfy the foreign key constraint, the operation will fail. @@ -839,13 +840,30 @@ CREATE TABLE order_items ( Analogous to ON DELETE there is also ON UPDATE which is invoked when a referenced column is changed (updated). The possible actions are the same. + In this case, CASCADE means that the updated values of the + referenced column(s) should be copied into the referencing row(s). + Normally, a referencing row need not satisfy the foreign key constraint + if any of its referencing columns are null. If MATCH FULL + is added to the foreign key declaration, a referencing row escapes + satisfying the constraint only if all its referencing columns are null + (so a mix of null and non-null values is guaranteed to fail a + MATCH FULL constraint). If you don't want referencing rows + to be able to avoid satisfying the foreign key constraint, declare the + referencing column(s) as NOT NULL. + + + + A foreign key must reference columns that either are a primary key or + form a unique constraint. This means that the referenced columns always + have an index (the one underlying the primary key or unique constraint); + so checks on whether a referencing row has a match will be efficient. Since a DELETE of a row from the referenced table or an UPDATE of a referenced column will require a scan of the referencing table for rows matching the old value, it - is often a good idea to index the referencing columns. Because this + is often a good idea to index the referencing columns too. Because this is not always needed, and there are many choices available on how to index, declaration of a foreign key constraint does not automatically create an index on the referencing columns. @@ -853,15 +871,8 @@ CREATE TABLE order_items ( More information about updating and deleting data is in . - - - - Finally, we should mention that a foreign key must reference - columns that either are a primary key or form a unique constraint. - If the foreign key references a unique constraint, there are some - additional possibilities regarding how null values are matched. - These are explained in the reference documentation for + linkend="dml">. Also see the description of foreign key constraint + syntax in the reference documentation for . diff --git a/doc/src/sgml/ref/create_table.sgml b/doc/src/sgml/ref/create_table.sgml index 1aea788584..1d7d31287f 100644 --- a/doc/src/sgml/ref/create_table.sgml +++ b/doc/src/sgml/ref/create_table.sgml @@ -585,8 +585,8 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXI These clauses specify a foreign key constraint, which requires that a group of one or more columns of the new table must only contain values that match values in the referenced - column(s) of some row of the referenced table. If refcolumn is omitted, the + column(s) of some row of the referenced table. If the refcolumn list is omitted, the primary key of the reftable is used. The referenced columns must be the columns of a non-deferrable unique or primary key constraint in the referenced table. Note that @@ -599,12 +599,16 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXI values of the referenced table and referenced columns using the given match type. There are three match types: MATCH FULL, MATCH PARTIAL, and MATCH - SIMPLE, which is also the default. MATCH + SIMPLE (which is the default). MATCH FULL will not allow one column of a multicolumn foreign key - to be null unless all foreign key columns are null. - MATCH SIMPLE allows some foreign key columns - to be null while other parts of the foreign key are not - null. MATCH PARTIAL is not yet implemented. + to be null unless all foreign key columns are null; if they are all + null, the row is not required to have a match in the referenced table. + MATCH SIMPLE allows any of the foreign key columns + to be null; if any of them are null, the row is not required to have a + match in the referenced table. + MATCH PARTIAL is not yet implemented. + (Of course, NOT NULL constraints can be applied to the + referencing column(s) to prevent these cases from arising.) @@ -652,8 +656,8 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXI Delete any rows referencing the deleted row, or update the - value of the referencing column to the new value of the - referenced column, respectively. + values of the referencing column(s) to the new values of the + referenced columns, respectively. @@ -672,6 +676,8 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXI Set the referencing column(s) to their default values. + (There must be a row in the referenced table matching the default + values, if they are not null, or the operation will fail.) @@ -680,8 +686,8 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXI If the referenced column(s) are changed frequently, it might be wise to - add an index to the foreign key column so that referential actions - associated with the foreign key column can be performed more + add an index to the referencing column(s) so that referential actions + associated with the foreign key constraint can be performed more efficiently. diff --git a/src/backend/utils/adt/ri_triggers.c b/src/backend/utils/adt/ri_triggers.c index ac252b8de2..f1fe5fa7f6 100644 --- a/src/backend/utils/adt/ri_triggers.c +++ b/src/backend/utils/adt/ri_triggers.c @@ -207,11 +207,6 @@ static void ri_BuildQueryKeyPkCheck(RI_QueryKey *key, int32 constr_queryno); static bool ri_KeysEqual(Relation rel, HeapTuple oldtup, HeapTuple newtup, const RI_ConstraintInfo *riinfo, bool rel_is_pk); -static bool ri_AllKeysUnequal(Relation rel, HeapTuple oldtup, HeapTuple newtup, - const RI_ConstraintInfo *riinfo, bool rel_is_pk); -static bool ri_OneKeyEqual(Relation rel, int column, - HeapTuple oldtup, HeapTuple newtup, - const RI_ConstraintInfo *riinfo, bool rel_is_pk); static bool ri_AttributesEqual(Oid eq_opr, Oid typeid, Datum oldvalue, Datum newvalue); static bool ri_Check_Pk_Match(Relation pk_rel, Relation fk_rel, @@ -1950,7 +1945,6 @@ RI_FKey_setnull_upd(PG_FUNCTION_ARGS) RI_QueryKey qkey; SPIPlanPtr qplan; int i; - bool use_cached_query; /* * Check that this is a valid trigger call on the right time and event. @@ -1985,7 +1979,7 @@ RI_FKey_setnull_upd(PG_FUNCTION_ARGS) /* ---------- * SQL3 11.9 * General rules 7) a) ii) 2): - * MATCH FULL + * MATCH SIMPLE/FULL * ... ON UPDATE SET NULL * ---------- */ @@ -2026,29 +2020,10 @@ RI_FKey_setnull_upd(PG_FUNCTION_ARGS) if (SPI_connect() != SPI_OK_CONNECT) elog(ERROR, "SPI_connect failed"); - /* - * "MATCH SIMPLE" only changes columns corresponding to the - * referenced columns that have changed in pk_rel. This means the - * "SET attrn=NULL [, attrn=NULL]" string will be change as well. - * In this case, we need to build a temporary plan rather than use - * our cached plan, unless the update happens to change all - * columns in the key. Fortunately, for the most common case of a - * single-column foreign key, this will be true. - * - * In case you're wondering, the inequality check works because we - * know that the old key value has no NULLs (see above). - */ - - use_cached_query = (riinfo.confmatchtype == FKCONSTR_MATCH_FULL) || - ri_AllKeysUnequal(pk_rel, old_row, new_row, - &riinfo, true); - /* * Fetch or prepare a saved plan for the set null update operation - * if possible, or build a temporary plan if not. */ - if (!use_cached_query || - (qplan = ri_FetchPreparedPlan(&qkey)) == NULL) + if ((qplan = ri_FetchPreparedPlan(&qkey)) == NULL) { StringInfoData querybuf; StringInfoData qualbuf; @@ -2080,37 +2055,23 @@ RI_FKey_setnull_upd(PG_FUNCTION_ARGS) quoteOneName(attname, RIAttName(fk_rel, riinfo.fk_attnums[i])); - - /* - * MATCH SIMPLE - only change columns corresponding - * to changed columns in pk_rel's key - */ - if (riinfo.confmatchtype == FKCONSTR_MATCH_FULL || - !ri_OneKeyEqual(pk_rel, i, old_row, new_row, - &riinfo, true)) - { - appendStringInfo(&querybuf, - "%s %s = NULL", - querysep, attname); - querysep = ","; - } + appendStringInfo(&querybuf, + "%s %s = NULL", + querysep, attname); sprintf(paramname, "$%d", i + 1); ri_GenerateQual(&qualbuf, qualsep, paramname, pk_type, riinfo.pf_eq_oprs[i], attname, fk_type); + querysep = ","; qualsep = "AND"; queryoids[i] = pk_type; } appendStringInfoString(&querybuf, qualbuf.data); - /* - * Prepare the plan. Save it only if we're building the - * "standard" plan. - */ + /* Prepare and save the plan */ qplan = ri_PlanCheck(querybuf.data, riinfo.nkeys, queryoids, - &qkey, fk_rel, pk_rel, - use_cached_query); + &qkey, fk_rel, pk_rel, true); } /* @@ -2463,25 +2424,15 @@ RI_FKey_setdefault_upd(PG_FUNCTION_ARGS) quoteOneName(attname, RIAttName(fk_rel, riinfo.fk_attnums[i])); - - /* - * MATCH SIMPLE - only change columns corresponding - * to changed columns in pk_rel's key - */ - if (riinfo.confmatchtype == FKCONSTR_MATCH_FULL || - !ri_OneKeyEqual(pk_rel, i, old_row, new_row, - &riinfo, true)) - { - appendStringInfo(&querybuf, - "%s %s = DEFAULT", - querysep, attname); - querysep = ","; - } + appendStringInfo(&querybuf, + "%s %s = DEFAULT", + querysep, attname); sprintf(paramname, "$%d", i + 1); ri_GenerateQual(&qualbuf, qualsep, paramname, pk_type, riinfo.pf_eq_oprs[i], attname, fk_type); + querysep = ","; qualsep = "AND"; queryoids[i] = pk_type; } @@ -3857,120 +3808,6 @@ ri_KeysEqual(Relation rel, HeapTuple oldtup, HeapTuple newtup, } -/* ---------- - * ri_AllKeysUnequal - - * - * Check if all key values in OLD and NEW are not equal. - * ---------- - */ -static bool -ri_AllKeysUnequal(Relation rel, HeapTuple oldtup, HeapTuple newtup, - const RI_ConstraintInfo *riinfo, bool rel_is_pk) -{ - TupleDesc tupdesc = RelationGetDescr(rel); - const int16 *attnums; - const Oid *eq_oprs; - int i; - - if (rel_is_pk) - { - attnums = riinfo->pk_attnums; - eq_oprs = riinfo->pp_eq_oprs; - } - else - { - attnums = riinfo->fk_attnums; - eq_oprs = riinfo->ff_eq_oprs; - } - - for (i = 0; i < riinfo->nkeys; i++) - { - Datum oldvalue; - Datum newvalue; - bool isnull; - - /* - * Get one attribute's oldvalue. If it is NULL - they're not equal. - */ - oldvalue = SPI_getbinval(oldtup, tupdesc, attnums[i], &isnull); - if (isnull) - continue; - - /* - * Get one attribute's newvalue. If it is NULL - they're not equal. - */ - newvalue = SPI_getbinval(newtup, tupdesc, attnums[i], &isnull); - if (isnull) - continue; - - /* - * Compare them with the appropriate equality operator. - */ - if (ri_AttributesEqual(eq_oprs[i], RIAttType(rel, attnums[i]), - oldvalue, newvalue)) - return false; /* found two equal items */ - } - - return true; -} - - -/* ---------- - * ri_OneKeyEqual - - * - * Check if one key value in OLD and NEW is equal. Note column is indexed - * from zero. - * - * ri_KeysEqual could call this but would run a bit slower. For - * now, let's duplicate the code. - * ---------- - */ -static bool -ri_OneKeyEqual(Relation rel, int column, HeapTuple oldtup, HeapTuple newtup, - const RI_ConstraintInfo *riinfo, bool rel_is_pk) -{ - TupleDesc tupdesc = RelationGetDescr(rel); - const int16 *attnums; - const Oid *eq_oprs; - Datum oldvalue; - Datum newvalue; - bool isnull; - - if (rel_is_pk) - { - attnums = riinfo->pk_attnums; - eq_oprs = riinfo->pp_eq_oprs; - } - else - { - attnums = riinfo->fk_attnums; - eq_oprs = riinfo->ff_eq_oprs; - } - - /* - * Get one attribute's oldvalue. If it is NULL - they're not equal. - */ - oldvalue = SPI_getbinval(oldtup, tupdesc, attnums[column], &isnull); - if (isnull) - return false; - - /* - * Get one attribute's newvalue. If it is NULL - they're not equal. - */ - newvalue = SPI_getbinval(newtup, tupdesc, attnums[column], &isnull); - if (isnull) - return false; - - /* - * Compare them with the appropriate equality operator. - */ - if (!ri_AttributesEqual(eq_oprs[column], RIAttType(rel, attnums[column]), - oldvalue, newvalue)) - return false; - - return true; -} - /* ---------- * ri_AttributesEqual - * diff --git a/src/test/regress/expected/foreign_key.out b/src/test/regress/expected/foreign_key.out index f86b39f396..305dfe20d4 100644 --- a/src/test/regress/expected/foreign_key.out +++ b/src/test/regress/expected/foreign_key.out @@ -557,7 +557,7 @@ SELECT * from FKTABLE; 2 | | 3 | 3 | 2 | 7 | 4 | 3 | 4 | 5 - 1 | | 3 | 1 + | | | 1 (6 rows) -- Try to delete something that should set default @@ -578,7 +578,7 @@ SELECT * from FKTABLE; 2 | | 3 | 3 | 2 | 7 | 4 | 3 | 4 | 5 - 1 | | 3 | 1 + | | | 1 0 | | | 1 (6 rows) @@ -599,7 +599,7 @@ SELECT * from FKTABLE; 2 | | 3 | 3 | 2 | 7 | 4 | 3 | 4 | 5 - 1 | | 3 | 1 + | | | 1 0 | | | 1 (6 rows) @@ -608,7 +608,7 @@ DROP TABLE PKTABLE; -- set default update / set null delete CREATE TABLE PKTABLE ( ptest1 int, ptest2 int, ptest3 int, ptest4 text, PRIMARY KEY(ptest1, ptest2, ptest3) ); NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "pktable_pkey" for table "pktable" -CREATE TABLE FKTABLE ( ftest1 int DEFAULT 0, ftest2 int DEFAULT -1, ftest3 int, ftest4 int, CONSTRAINT constrname3 +CREATE TABLE FKTABLE ( ftest1 int DEFAULT 0, ftest2 int DEFAULT -1, ftest3 int DEFAULT -2, ftest4 int, CONSTRAINT constrname3 FOREIGN KEY(ftest1, ftest2, ftest3) REFERENCES PKTABLE ON DELETE SET NULL ON UPDATE SET DEFAULT); -- Insert Primary Key values @@ -645,9 +645,9 @@ SELECT * from FKTABLE; -- Try to update something that will fail UPDATE PKTABLE set ptest2=5 where ptest2=2; ERROR: insert or update on table "fktable" violates foreign key constraint "constrname3" -DETAIL: Key (ftest1, ftest2, ftest3)=(1, -1, 3) is not present in table "pktable". +DETAIL: Key (ftest1, ftest2, ftest3)=(0, -1, -2) is not present in table "pktable". -- Try to update something that will set default -UPDATE PKTABLE set ptest1=0, ptest2=5, ptest3=10 where ptest2=2; +UPDATE PKTABLE set ptest1=0, ptest2=-1, ptest3=-2 where ptest2=2; UPDATE PKTABLE set ptest2=10 where ptest2=4; -- Try to update something that should not set default UPDATE PKTABLE set ptest2=2 WHERE ptest2=3 and ptest1=1; @@ -657,7 +657,7 @@ SELECT * from PKTABLE; --------+--------+--------+-------- 2 | 3 | 4 | test3 2 | -1 | 5 | test5 - 0 | 5 | 10 | test1 + 0 | -1 | -2 | test1 2 | 10 | 5 | test4 1 | 2 | 3 | test2 (5 rows) @@ -670,8 +670,8 @@ SELECT * from FKTABLE; 2 | | 3 | 3 | 2 | 7 | 4 | 3 | 4 | 5 - 0 | -1 | | 1 - 2 | -1 | 5 | 1 + 0 | -1 | -2 | 1 + 0 | -1 | -2 | 1 (7 rows) -- Try to delete something that should set null @@ -681,7 +681,7 @@ SELECT * from PKTABLE; ptest1 | ptest2 | ptest3 | ptest4 --------+--------+--------+-------- 2 | -1 | 5 | test5 - 0 | 5 | 10 | test1 + 0 | -1 | -2 | test1 2 | 10 | 5 | test4 1 | 2 | 3 | test2 (4 rows) @@ -693,18 +693,18 @@ SELECT * from FKTABLE; 2 | | 3 | 3 | 2 | 7 | 4 | 3 | 4 | 5 - 0 | -1 | | 1 - 2 | -1 | 5 | 1 + 0 | -1 | -2 | 1 + 0 | -1 | -2 | 1 | | | 1 (7 rows) -- Try to delete something that should not set null -DELETE FROM PKTABLE where ptest2=5; +DELETE FROM PKTABLE where ptest2=-1 and ptest3=5; -- Show PKTABLE and FKTABLE SELECT * from PKTABLE; ptest1 | ptest2 | ptest3 | ptest4 --------+--------+--------+-------- - 2 | -1 | 5 | test5 + 0 | -1 | -2 | test1 2 | 10 | 5 | test4 1 | 2 | 3 | test2 (3 rows) @@ -716,8 +716,8 @@ SELECT * from FKTABLE; 2 | | 3 | 3 | 2 | 7 | 4 | 3 | 4 | 5 - 0 | -1 | | 1 - 2 | -1 | 5 | 1 + 0 | -1 | -2 | 1 + 0 | -1 | -2 | 1 | | | 1 (7 rows) diff --git a/src/test/regress/sql/foreign_key.sql b/src/test/regress/sql/foreign_key.sql index 2c4c0c5606..874d9f7a33 100644 --- a/src/test/regress/sql/foreign_key.sql +++ b/src/test/regress/sql/foreign_key.sql @@ -367,7 +367,7 @@ DROP TABLE PKTABLE; -- set default update / set null delete CREATE TABLE PKTABLE ( ptest1 int, ptest2 int, ptest3 int, ptest4 text, PRIMARY KEY(ptest1, ptest2, ptest3) ); -CREATE TABLE FKTABLE ( ftest1 int DEFAULT 0, ftest2 int DEFAULT -1, ftest3 int, ftest4 int, CONSTRAINT constrname3 +CREATE TABLE FKTABLE ( ftest1 int DEFAULT 0, ftest2 int DEFAULT -1, ftest3 int DEFAULT -2, ftest4 int, CONSTRAINT constrname3 FOREIGN KEY(ftest1, ftest2, ftest3) REFERENCES PKTABLE ON DELETE SET NULL ON UPDATE SET DEFAULT); @@ -397,7 +397,7 @@ SELECT * from FKTABLE; UPDATE PKTABLE set ptest2=5 where ptest2=2; -- Try to update something that will set default -UPDATE PKTABLE set ptest1=0, ptest2=5, ptest3=10 where ptest2=2; +UPDATE PKTABLE set ptest1=0, ptest2=-1, ptest3=-2 where ptest2=2; UPDATE PKTABLE set ptest2=10 where ptest2=4; -- Try to update something that should not set default @@ -415,7 +415,7 @@ SELECT * from PKTABLE; SELECT * from FKTABLE; -- Try to delete something that should not set null -DELETE FROM PKTABLE where ptest2=5; +DELETE FROM PKTABLE where ptest2=-1 and ptest3=5; -- Show PKTABLE and FKTABLE SELECT * from PKTABLE;