diff --git a/pkg/sql/check.go b/pkg/sql/check.go index 2a89f00aec0b..39779b952b9c 100644 --- a/pkg/sql/check.go +++ b/pkg/sql/check.go @@ -61,6 +61,81 @@ func validateCheckExpr( return nil } +// matchFullUnacceptableKeyQuery generates and returns a query for rows that are +// disallowed given the specified MATCH FULL composite FK reference, i.e., rows +// in the referencing table where the key contains both null and non-null +// values. +// +// For example, a FK constraint on columns (a_id, b_id) with an index c_id on +// the table "child" would require the following query: +// +// SELECT * FROM child@c_idx +// WHERE +// NOT ((COALESCE(a_id, b_id) IS NULL) OR (a_id IS NOT NULL AND b_id IS NOT NULL)) +// LIMIT 1; +func matchFullUnacceptableKeyQuery( + prefix int, srcName *string, srcIdx *sqlbase.IndexDescriptor, +) string { + srcCols, srcNotNullClause := make([]string, prefix), make([]string, prefix) + for i := 0; i < prefix; i++ { + srcCols[i] = tree.NameString(srcIdx.ColumnNames[i]) + srcNotNullClause[i] = fmt.Sprintf("%s IS NOT NULL", tree.NameString(srcIdx.ColumnNames[i])) + } + return fmt.Sprintf( + `SELECT * FROM %s@%s WHERE NOT ((COALESCE(%s) IS NULL) OR (%s)) LIMIT 1`, + *srcName, tree.NameString(srcIdx.Name), + strings.Join(srcCols, ", "), + strings.Join(srcNotNullClause, " AND "), + ) +} + +// nonMatchingRowQuery generates and returns a query for rows that violate the +// specified FK constraint, i.e., rows in the referencing table with no matching +// key in the referenced table. Rows in the referencing table with any null +// values in the key are excluded from matching (for both MATCH FULL and MATCH +// SIMPLE). +// +// For example, a FK constraint on columns (a_id, b_id) with an index c_id on +// the table "child", referencing columns (a, b) with an index p_id on the table +// "parent", would require the following query: +// +// SELECT +// s.a_id, s.b_id +// FROM +// (SELECT * FROM child@c_idx WHERE a_id IS NOT NULL AND b_id IS NOT NULL) AS s +// LEFT OUTER JOIN parent@p_idx AS t ON s.a_id = t.a AND s.b_id = t.b +// WHERE +// t.a IS NULL +// LIMIT 1; +func nonMatchingRowQuery( + prefix int, + srcName *string, + srcIdx *sqlbase.IndexDescriptor, + targetName *string, + targetIdx *sqlbase.IndexDescriptor, +) string { + srcCols, srcWhere, targetCols, on := make([]string, prefix), make([]string, prefix), make([]string, prefix), make([]string, prefix) + + for i := 0; i < prefix; i++ { + // s and t are table aliases used in the query + srcCols[i] = fmt.Sprintf("s.%s", tree.NameString(srcIdx.ColumnNames[i])) + srcWhere[i] = fmt.Sprintf("%s IS NOT NULL", tree.NameString(srcIdx.ColumnNames[i])) + targetCols[i] = fmt.Sprintf("t.%s", tree.NameString(targetIdx.ColumnNames[i])) + on[i] = fmt.Sprintf("%s = %s", srcCols[i], targetCols[i]) + } + + return fmt.Sprintf( + `SELECT %s FROM (SELECT * FROM %s@%s WHERE %s) AS s LEFT OUTER JOIN %s@%s AS t ON %s WHERE %s IS NULL LIMIT 1`, + strings.Join(srcCols, ", "), + *srcName, tree.NameString(srcIdx.Name), + strings.Join(srcWhere, " AND "), + *targetName, tree.NameString(targetIdx.Name), + strings.Join(on, " AND "), + // Sufficient to check the first column to see whether there was no matching row + targetCols[0], + ) +} + func (p *planner) validateForeignKey( ctx context.Context, srcTable *sqlbase.TableDescriptor, srcIdx *sqlbase.IndexDescriptor, ) error { @@ -88,28 +163,54 @@ func (p *planner) validateForeignKey( prefix = p } - srcCols, targetCols := make([]string, prefix), make([]string, prefix) - join, where := make([]string, prefix), make([]string, prefix) + // For MATCH FULL FKs, first check whether any disallowed keys containing both + // null and non-null values exist. + // (The matching options only matter for FKs with more than one column.) + if prefix > 1 && srcIdx.ForeignKey.Match == sqlbase.ForeignKeyReference_FULL { + query := matchFullUnacceptableKeyQuery(prefix, &srcName, srcIdx) - for i := 0; i < prefix; i++ { - srcCols[i] = fmt.Sprintf("s.%s", tree.NameString(srcIdx.ColumnNames[i])) - targetCols[i] = fmt.Sprintf("t.%s", tree.NameString(targetIdx.ColumnNames[i])) - join[i] = fmt.Sprintf("(%s = %s OR (%s IS NULL AND %s IS NULL))", - srcCols[i], targetCols[i], srcCols[i], targetCols[i]) - where[i] = fmt.Sprintf("(%s IS NOT NULL AND %s IS NULL)", srcCols[i], targetCols[i]) - } + log.Infof(ctx, "Validating MATCH FULL FK %q (%q [%v] -> %q [%v]) with query %q", + srcIdx.ForeignKey.Name, + srcTable.Name, srcIdx.ColumnNames, targetTable.Name, targetIdx.ColumnNames, + query, + ) - query := fmt.Sprintf( - `SELECT %s FROM %s@%s AS s LEFT OUTER JOIN %s@%s AS t ON %s WHERE %s LIMIT 1`, - strings.Join(srcCols, ", "), - srcName, tree.NameString(srcIdx.Name), targetName, tree.NameString(targetIdx.Name), - strings.Join(join, " AND "), - strings.Join(where, " OR "), - ) + rows, err := p.delegateQuery(ctx, "ALTER TABLE VALIDATE", query, nil, nil) + if err != nil { + return err + } + + rows, err = p.optimizePlan(ctx, rows, allColumns(rows)) + if err != nil { + return err + } + defer rows.Close(ctx) + + params := runParams{ + ctx: ctx, + extendedEvalCtx: &p.extendedEvalCtx, + p: p, + } + if err := startPlan(params, rows); err != nil { + return err + } + next, err := rows.Next(params) + if err != nil { + return err + } + + if next { + return pgerror.NewErrorf(pgerror.CodeForeignKeyViolationError, + "foreign key violation: MATCH FULL does not allow mixing of null and nonnull values %s for %s", + rows.Values(), srcIdx.ForeignKey.Name, + ) + } + } + query := nonMatchingRowQuery(prefix, &srcName, srcIdx, &targetName, targetIdx) log.Infof(ctx, "Validating FK %q (%q [%v] -> %q [%v]) with query %q", srcIdx.ForeignKey.Name, - srcTable.Name, srcCols, targetTable.Name, targetCols, + srcTable.Name, srcIdx.ColumnNames, targetTable.Name, targetIdx.ColumnNames, query, ) diff --git a/pkg/sql/logictest/testdata/logic_test/fk b/pkg/sql/logictest/testdata/logic_test/fk index f9a4e759c347..2947abed696b 100644 --- a/pkg/sql/logictest/testdata/logic_test/fk +++ b/pkg/sql/logictest/testdata/logic_test/fk @@ -351,6 +351,11 @@ statement ok ALTER TABLE "user content"."customer reviews" ADD CONSTRAINT orderfk2 FOREIGN KEY ("order", shipment) REFERENCES orders (id, shipment) +# This is allowed because we match using MATCH SIMPLE. +statement ok +ALTER TABLE "user content"."customer reviews" + VALIDATE CONSTRAINT orderfk2 + # This is allowed because we match using MATCH SIMPLE. statement ok INSERT INTO "user content"."customer reviews" (id, product, body, "order") VALUES (4, '780', 'i ordered 101 of them', 9) @@ -361,17 +366,6 @@ INSERT INTO "user content"."customer reviews" (id, product, body, "order", shipm statement error pgcode 23503 foreign key violation: value \[1 9\] not found in orders@primary \[id shipment\] INSERT INTO "user content"."customer reviews" (id, product, body, shipment, "order") VALUES (4, '780', 'i ordered 101 of them', 9, 1) -statement error pgcode 23503 foreign key violation: "customer reviews" row order=9, shipment=NULL has no match in "orders" -ALTER TABLE "user content"."customer reviews" - VALIDATE CONSTRAINT orderfk2 - -statement ok -DELETE FROM "user content"."customer reviews" WHERE "order" = 9 - -statement ok -ALTER TABLE "user content"."customer reviews" - VALIDATE CONSTRAINT orderfk2 - statement ok ALTER TABLE delivery DROP CONSTRAINT fk_order_ref_orders @@ -1492,6 +1486,245 @@ INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, 'y1', 'z1') statement ok INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, NULL, NULL) +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x2', NULL, NULL) + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, 'y2', NULL) + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, NULL, 'z2') + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x2', 'y2', NULL) + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x2', NULL, 'z2') + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, 'y2', 'z2') + +statement ok +DROP TABLE b, a + +subtest Composite_Simple_Unvalidated +# Test inserting into table with an unvalidated constraint, and running VALIDATE CONSTRAINT later + +# Test composite key with two columns. +statement ok +CREATE TABLE a ( + x STRING NULL + ,y STRING NULL + ,CONSTRAINT "primary" PRIMARY KEY (y, x) +); + +statement ok +CREATE TABLE b ( + a_y STRING NULL + ,a_x STRING NULL +); + +# Add the constraint separately so that it's unvalidated, so we can test VALIDATE CONSTRAINT. +statement ok +ALTER TABLE b ADD CONSTRAINT fk_ref FOREIGN KEY (a_y, a_x) REFERENCES a (y, x) + +statement ok +INSERT INTO a (x, y) VALUES ('x1', 'y1') + +# All of these are allowed because we do composite matching using MATCH SIMPLE. +statement ok +INSERT INTO b (a_x) VALUES ('x1') + +statement ok +INSERT INTO b (a_y) VALUES ('y1') + +statement ok +INSERT INTO b (a_y, a_x) VALUES ('y1', NULL) + +statement ok +INSERT INTO b (a_y, a_x) VALUES (NULL, 'x1') + +statement ok +INSERT INTO b (a_y, a_x) VALUES ('y2', NULL) + +statement ok +INSERT INTO b (a_y, a_x) VALUES (NULL, 'x2') + +statement ok +INSERT INTO b (a_x, a_y) VALUES ('x1', 'y1') + +statement ok +INSERT INTO b (a_x, a_y) VALUES (NULL, NULL) + +statement ok +ALTER TABLE b VALIDATE CONSTRAINT fk_ref + +statement ok +DROP TABLE b, a + +# Test composite key with three columns. +statement ok +CREATE TABLE a ( + x STRING NULL + ,y STRING NULL + ,z STRING NULL + ,CONSTRAINT "primary" PRIMARY KEY (z, y, x) +); + +statement ok +CREATE TABLE b ( + a_y STRING NULL + ,a_x STRING NULL + ,a_z STRING NULL +); + +# Add the constraint separately so that it's unvalidated, so we can test VALIDATE CONSTRAINT. +statement ok +ALTER TABLE b ADD CONSTRAINT fk_ref FOREIGN KEY (a_z, a_y, a_x) REFERENCES a (z, y, x) + +statement ok +INSERT INTO a (x, y, z) VALUES ('x1', 'y1', 'z1') + +# All of these are allowed because we do composite matching using MATCH SIMPLE. +statement ok +INSERT INTO b (a_x) VALUES ('x1') + +statement ok +INSERT INTO b (a_y) VALUES ('y1') + +statement ok +INSERT INTO b (a_z) VALUES ('z1') + +statement ok +INSERT INTO b (a_x, a_y) VALUES ('x1', 'y1') + +statement ok +INSERT INTO b (a_x, a_y) VALUES (NULL, 'y1') + +statement ok +INSERT INTO b (a_x, a_y) VALUES ('x1', NULL) + +statement ok +INSERT INTO b (a_x, a_z) VALUES ('x1', 'z1') + +statement ok +INSERT INTO b (a_x, a_z) VALUES (NULL, 'z1') + +statement ok +INSERT INTO b (a_x, a_z) VALUES ('x1', NULL) + +statement ok +INSERT INTO b (a_y, a_z) VALUES ('y1', 'z1') + +statement ok +INSERT INTO b (a_y, a_z) VALUES (NULL, 'z1') + +statement ok +INSERT INTO b (a_y, a_z) VALUES ('y1', NULL) + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x1', NULL, NULL) + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, 'y1', NULL) + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, NULL, 'z1') + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x1', 'y1', NULL) + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x1', NULL, 'z1') + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, 'y1', 'z1') + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x2', NULL, NULL) + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, 'y2', NULL) + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, NULL, 'z2') + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x2', 'y2', NULL) + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x2', NULL, 'z2') + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, 'y2', 'z2') + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, NULL, NULL) + +statement ok +ALTER TABLE b VALIDATE CONSTRAINT fk_ref + +statement ok +DROP TABLE b, a + +subtest Composite_Simple_Validate_Constraint_Invalid +# Test VALIDATE CONSTRAINT by inserting invalid rows before the constraint is added, one at a time. + +statement ok +CREATE TABLE a ( + x STRING NULL + ,y STRING NULL + ,z STRING NULL + ,CONSTRAINT "primary" PRIMARY KEY (z, y, x) +); + +statement ok +CREATE TABLE b ( + a_y STRING NULL + ,a_x STRING NULL + ,a_z STRING NULL + ,INDEX idx (a_z, a_y, a_x) +); + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x2', 'y1', 'z1') + +statement ok +ALTER TABLE b ADD CONSTRAINT fk_ref FOREIGN KEY (a_z, a_y, a_x) REFERENCES a (z, y, x) + +statement error foreign key violation: "b" row a_z='z1', a_y='y1', a_x='x2' has no match in "a" +ALTER TABLE b VALIDATE CONSTRAINT fk_ref + +statement ok +TRUNCATE b + +statement ok +ALTER TABLE b DROP CONSTRAINT fk_ref + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x2', 'y2', 'z1') + +statement ok +ALTER TABLE b ADD CONSTRAINT fk_ref FOREIGN KEY (a_z, a_y, a_x) REFERENCES a (z, y, x) + +statement error foreign key violation: "b" row a_z='z1', a_y='y2', a_x='x2' has no match in "a" +ALTER TABLE b VALIDATE CONSTRAINT fk_ref + +statement ok +TRUNCATE b + +statement ok +ALTER TABLE b DROP CONSTRAINT fk_ref + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x2', 'y2', 'z2') + +statement ok +ALTER TABLE b ADD CONSTRAINT fk_ref FOREIGN KEY (a_z, a_y, a_x) REFERENCES a (z, y, x) + +statement error foreign key violation: "b" row a_z='z2', a_y='y2', a_x='x2' has no match in "a" +ALTER TABLE b VALIDATE CONSTRAINT fk_ref + statement ok DROP TABLE b, a @@ -1621,6 +1854,295 @@ INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, NULL, NULL) statement ok DROP TABLE b, a +subtest Composite_Full_Validate_Later +# Test inserting into table with an unvalidated constraint, and running VALIDATE CONSTRAINT later + +# Test composite key with two columns. +statement ok +CREATE TABLE a ( + x STRING NULL + ,y STRING NULL + ,CONSTRAINT "primary" PRIMARY KEY (y, x) +); + +statement ok +CREATE TABLE b ( + a_y STRING NULL + ,a_x STRING NULL +); + +# Add the constraint separately so that it's unvalidated, so we can test VALIDATE CONSTRAINT. +statement ok +ALTER TABLE b ADD CONSTRAINT fk_ref FOREIGN KEY (a_y, a_x) REFERENCES a (y, x) MATCH FULL + +statement ok +INSERT INTO a (x, y) VALUES ('x1', 'y1') + +# These statements should all fail because this uses MATCH FULL. +statement error missing value for column "a_y" in multi-part foreign key +INSERT INTO b (a_x) VALUES ('x1') + +statement error missing value for column "a_x" in multi-part foreign key +INSERT INTO b (a_y) VALUES ('y1') + +statement error foreign key violation: MATCH FULL does not allow mixing of null and nonnull values +INSERT INTO b (a_y, a_x) VALUES ('y1', NULL) + +statement error foreign key violation: MATCH FULL does not allow mixing of null and nonnull values +INSERT INTO b (a_y, a_x) VALUES (NULL, 'x1') + +# These next two statements should still be allowed. +statement ok +INSERT INTO b (a_x, a_y) VALUES ('x1', 'y1') + +statement ok +INSERT INTO b (a_x, a_y) VALUES (NULL, NULL) + +statement ok +ALTER TABLE b VALIDATE CONSTRAINT fk_ref + +statement ok +DROP TABLE b, a + +# Test composite key with three columns. +statement ok +CREATE TABLE a ( + x STRING NULL + ,y STRING NULL + ,z STRING NULL + ,CONSTRAINT "primary" PRIMARY KEY (z, y, x) +); + +statement ok +CREATE TABLE b ( + a_y STRING NULL + ,a_x STRING NULL + ,a_z STRING NULL +); + +# Add the constraint separately so that it's unvalidated, so we can test VALIDATE CONSTRAINT. +statement ok +ALTER TABLE b ADD CONSTRAINT fk_ref FOREIGN KEY (a_z, a_y, a_x) REFERENCES a (z, y, x) MATCH FULL + +statement ok +INSERT INTO a (x, y, z) VALUES ('x1', 'y1', 'z1') + +# These statements should all fail because this uses MATCH FULL. +statement error missing values for columns \["a_y" "a_z"\] in multi-part foreign key +INSERT INTO b (a_x) VALUES ('x1') + +statement error missing values for columns \["a_x" "a_z"\] in multi-part foreign key +INSERT INTO b (a_y) VALUES ('y1') + +statement error missing values for columns \["a_x" "a_y"\] in multi-part foreign key +INSERT INTO b (a_z) VALUES ('z1') + +statement error missing value for column "a_z" in multi-part foreign key +INSERT INTO b (a_x, a_y) VALUES ('x1', 'y1') + +statement error missing value for column "a_z" in multi-part foreign key +INSERT INTO b (a_x, a_y) VALUES (NULL, 'y1') + +statement error missing value for column "a_z" in multi-part foreign key +INSERT INTO b (a_x, a_y) VALUES ('x1', NULL) + +statement error missing value for column "a_y" in multi-part foreign key +INSERT INTO b (a_x, a_z) VALUES ('x1', 'z1') + +statement error missing value for column "a_y" in multi-part foreign key +INSERT INTO b (a_x, a_z) VALUES (NULL, 'z1') + +statement error missing value for column "a_y" in multi-part foreign key +INSERT INTO b (a_x, a_z) VALUES ('x1', NULL) + +statement error missing value for column "a_x" in multi-part foreign key +INSERT INTO b (a_y, a_z) VALUES ('y1', 'z1') + +statement error missing value for column "a_x" in multi-part foreign key +INSERT INTO b (a_y, a_z) VALUES (NULL, 'z1') + +statement error missing value for column "a_x" in multi-part foreign key +INSERT INTO b (a_y, a_z) VALUES ('y1', NULL) + +statement error foreign key violation: MATCH FULL does not allow mixing of null and nonnull values +INSERT INTO b (a_x, a_y, a_z) VALUES ('x1', NULL, NULL) + +statement error foreign key violation: MATCH FULL does not allow mixing of null and nonnull values +INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, 'y1', NULL) + +statement error foreign key violation: MATCH FULL does not allow mixing of null and nonnull values +INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, NULL, 'z1') + +statement error foreign key violation: MATCH FULL does not allow mixing of null and nonnull values +INSERT INTO b (a_x, a_y, a_z) VALUES ('x1', 'y1', NULL) + +statement error foreign key violation: MATCH FULL does not allow mixing of null and nonnull values +INSERT INTO b (a_x, a_y, a_z) VALUES ('x1', NULL, 'z1') + +statement error foreign key violation: MATCH FULL does not allow mixing of null and nonnull values +INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, 'y1', 'z1') + +# This statement should still be allowed. +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, NULL, NULL) + +statement ok +ALTER TABLE b VALIDATE CONSTRAINT fk_ref + +statement ok +DROP TABLE b, a + +subtest Composite_Full_Validate_Constraint_Invalid +# Test VALIDATE CONSTRAINT by inserting invalid rows before the constraint is added, one at a time. + +statement ok +CREATE TABLE a ( + x STRING NULL + ,y STRING NULL + ,z STRING NULL + ,CONSTRAINT "primary" PRIMARY KEY (z, y, x) +); + +statement ok +CREATE TABLE b ( + a_y STRING NULL + ,a_x STRING NULL + ,a_z STRING NULL + ,INDEX idx (a_z, a_y, a_x) +); + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x1', NULL, NULL) + +statement ok +ALTER TABLE b ADD CONSTRAINT fk_ref FOREIGN KEY (a_z, a_y, a_x) REFERENCES a (z, y, x) MATCH FULL + +statement error foreign key violation: MATCH FULL does not allow mixing of null and nonnull values +ALTER TABLE b VALIDATE CONSTRAINT fk_ref + +statement ok +TRUNCATE b + +statement ok +ALTER TABLE b DROP CONSTRAINT fk_ref + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, 'y1', NULL) + +statement ok +ALTER TABLE b ADD CONSTRAINT fk_ref FOREIGN KEY (a_z, a_y, a_x) REFERENCES a (z, y, x) MATCH FULL + +statement error foreign key violation: MATCH FULL does not allow mixing of null and nonnull values +ALTER TABLE b VALIDATE CONSTRAINT fk_ref + +statement ok +TRUNCATE b + +statement ok +ALTER TABLE b DROP CONSTRAINT fk_ref + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, NULL, 'z1') + +statement ok +ALTER TABLE b ADD CONSTRAINT fk_ref FOREIGN KEY (a_z, a_y, a_x) REFERENCES a (z, y, x) MATCH FULL + +statement error foreign key violation: MATCH FULL does not allow mixing of null and nonnull values +ALTER TABLE b VALIDATE CONSTRAINT fk_ref + +statement ok +TRUNCATE b + +statement ok +ALTER TABLE b DROP CONSTRAINT fk_ref + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x1', 'y1', NULL) + +statement ok +ALTER TABLE b ADD CONSTRAINT fk_ref FOREIGN KEY (a_z, a_y, a_x) REFERENCES a (z, y, x) MATCH FULL + +statement error foreign key violation: MATCH FULL does not allow mixing of null and nonnull values +ALTER TABLE b VALIDATE CONSTRAINT fk_ref + +statement ok +TRUNCATE b + +statement ok +ALTER TABLE b DROP CONSTRAINT fk_ref + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x1', NULL, 'z1') + +statement ok +ALTER TABLE b ADD CONSTRAINT fk_ref FOREIGN KEY (a_z, a_y, a_x) REFERENCES a (z, y, x) MATCH FULL + +statement error foreign key violation: MATCH FULL does not allow mixing of null and nonnull values +ALTER TABLE b VALIDATE CONSTRAINT fk_ref + +statement ok +TRUNCATE b + +statement ok +ALTER TABLE b DROP CONSTRAINT fk_ref + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES (NULL, 'y1', 'z1') + +statement ok +ALTER TABLE b ADD CONSTRAINT fk_ref FOREIGN KEY (a_z, a_y, a_x) REFERENCES a (z, y, x) MATCH FULL + +statement error foreign key violation: MATCH FULL does not allow mixing of null and nonnull values +ALTER TABLE b VALIDATE CONSTRAINT fk_ref + +statement ok +TRUNCATE b + +statement ok +ALTER TABLE b DROP CONSTRAINT fk_ref + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x2', 'y1', 'z1') + +statement ok +ALTER TABLE b ADD CONSTRAINT fk_ref FOREIGN KEY (a_z, a_y, a_x) REFERENCES a (z, y, x) MATCH FULL + +statement error foreign key violation: "b" row a_z='z1', a_y='y1', a_x='x2' has no match in "a" +ALTER TABLE b VALIDATE CONSTRAINT fk_ref + +statement ok +TRUNCATE b + +statement ok +ALTER TABLE b DROP CONSTRAINT fk_ref + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x2', 'y2', 'z1') + +statement ok +ALTER TABLE b ADD CONSTRAINT fk_ref FOREIGN KEY (a_z, a_y, a_x) REFERENCES a (z, y, x) MATCH FULL + +statement error foreign key violation: "b" row a_z='z1', a_y='y2', a_x='x2' has no match in "a" +ALTER TABLE b VALIDATE CONSTRAINT fk_ref + +statement ok +TRUNCATE b + +statement ok +ALTER TABLE b DROP CONSTRAINT fk_ref + +statement ok +INSERT INTO b (a_x, a_y, a_z) VALUES ('x2', 'y2', 'z2') + +statement ok +ALTER TABLE b ADD CONSTRAINT fk_ref FOREIGN KEY (a_z, a_y, a_x) REFERENCES a (z, y, x) MATCH FULL + +statement error foreign key violation: "b" row a_z='z2', a_y='y2', a_x='x2' has no match in "a" +ALTER TABLE b VALIDATE CONSTRAINT fk_ref + +statement ok +DROP TABLE b, a + subtest auto_add_fk_with_composite_index_to_empty_table statement ok