*** pgsql.virg/src/backend/commands/command.c Sat Apr 14 16:02:15 2001 --- pgsql/src/backend/commands/command.c Sun Apr 15 04:11:15 2001 *************** *** 39,44 **** --- 39,45 ---- #include "parser/parse_expr.h" #include "parser/parse_clause.h" #include "parser/parse_relation.h" + #include "parser/parse_oper.h" #include "nodes/makefuncs.h" #include "optimizer/planmain.h" #include "optimizer/clauses.h" *************** *** 1248,1253 **** --- 1249,1261 ---- int i; bool found = false; + Oid fktypoid[INDEX_MAX_KEYS]; + Oid pktypoid[INDEX_MAX_KEYS]; + int attloc; + + for (i=0; ipktable_name) && !is_temp_rel_name(relationName)) elog(ERROR, "ALTER TABLE / ADD CONSTRAINT: Unable to reference temporary table from permanent table constraint."); *************** *** 1309,1314 **** --- 1317,1323 ---- found = false; else { + attloc=0; /* go through the fkconstraint->pk_attrs list */ foreach(attrl, fkconstraint->pk_attrs) { *************** *** 1325,1330 **** --- 1334,1344 ---- if (strcmp(name, attr->name) == 0) { + /* We get the type of this attribute here and + * store it so we can use it later for making + * sure the types are comparable. + */ + pktypoid[attloc++]=rel_attrs[pkattno-1]->atttypid; found = true; break; } *************** *** 1354,1359 **** --- 1368,1374 ---- Ident *fkattr; found = false; + attloc = 0; foreach(fkattrs, fkconstraint->fk_attrs) { int count; *************** *** 1366,1371 **** --- 1381,1391 ---- if (strcmp(name, fkattr->name) == 0) { + /* + * Here once again we get the types, this + * time for the fk table's attributes + */ + fktypoid[attloc++]=rel->rd_att->attrs[count]->atttypid; found = true; break; } *************** *** 1375,1380 **** --- 1395,1411 ---- } if (!found) elog(ERROR, "columns referenced in foreign key constraint not found."); + } + + for (i=0; i < INDEX_MAX_KEYS && fktypoid[i] !=0; i++) { + /* + * fktypoid[i] is the foreign key table's i'th element's type oid + * pktypoid[i] is the primary key table's i'th element's type oid + * We let oper() do our work for us, including elog(ERROR) if the + * types can't compare with = + */ + Operator o=oper("=", fktypoid[i], pktypoid[i], false); + ReleaseSysCache(o); } trig.tgoid = 0; *** pgsql.virg/src/backend/parser/analyze.c Sat Apr 14 16:03:55 2001 --- pgsql/src/backend/parser/analyze.c Sun Apr 15 04:43:43 2001 *************** *** 24,29 **** --- 24,31 ---- #include "parser/parse_agg.h" #include "parser/parse_clause.h" #include "parser/parse_coerce.h" + #include "parser/parse_expr.h" + #include "parser/parse_oper.h" #include "parser/parse_relation.h" #include "parser/parse_target.h" #include "parser/parse_type.h" *************** *** 52,61 **** static List *getSetColTypes(ParseState *pstate, Node *node); static void transformForUpdate(Query *qry, List *forUpdate); ! static void transformFkeyGetPrimaryKey(FkConstraint *fkconstraint); static void transformConstraintAttrs(List *constraintList); static void transformColumnType(ParseState *pstate, ColumnDef *column); ! static void transformFkeyCheckAttrs(FkConstraint *fkconstraint); static void release_pstate_resources(ParseState *pstate); static FromExpr *makeFromExpr(List *fromlist, Node *quals); --- 54,63 ---- static List *getSetColTypes(ParseState *pstate, Node *node); static void transformForUpdate(Query *qry, List *forUpdate); ! static void transformFkeyGetPrimaryKey(FkConstraint *fkconstraint, Oid *pktypoid); static void transformConstraintAttrs(List *constraintList); static void transformColumnType(ParseState *pstate, ColumnDef *column); ! static void transformFkeyCheckAttrs(FkConstraint *fkconstraint, Oid *pktypoid); static void release_pstate_resources(ParseState *pstate); static FromExpr *makeFromExpr(List *fromlist, Node *quals); *************** *** 1139,1145 **** --- 1141,1153 ---- List *fk_attr; List *pk_attr; Ident *id; + Oid pktypoid[INDEX_MAX_KEYS]; + Oid fktypoid[INDEX_MAX_KEYS]; + int i; + for (i=0; ifk_attrs != NIL) { int found = 0; + int attnum=0; List *cols; List *fkattrs; Ident *fkattr = NULL; *************** *** 1174,1219 **** col = lfirst(cols); if (strcmp(col->colname, fkattr->name) == 0) { found = 1; break; } } ! if (!found) ! break; ! } ! if (!found) ! { /* try inherited tables */ ! List *inher; ! List *inhRelnames = stmt->inhRelnames; ! Relation rel; ! ! foreach(inher, inhRelnames) ! { ! Value *inh = lfirst(inher); ! int count; ! Assert(IsA(inh, String)); ! rel = heap_openr(strVal(inh), AccessShareLock); ! if (rel->rd_rel->relkind != RELKIND_RELATION) ! elog(ERROR, "inherited table \"%s\" is not a relation", ! strVal(inh)); ! for (count = 0; count < rel->rd_att->natts; count++) { ! char *name = NameStr(rel->rd_att->attrs[count]->attname); ! if (strcmp(fkattr->name, name) == 0) { ! found = 1; ! break; } } - heap_close(rel, NoLock); - if (found) - break; } } - else - found = 1; if (!found) elog(ERROR, "columns referenced in foreign key constraint not found."); } --- 1183,1232 ---- col = lfirst(cols); if (strcmp(col->colname, fkattr->name) == 0) { + char *buff=TypeNameToInternalName(col->typename); + Oid type=typenameTypeId(buff); + if (!OidIsValid(type)) { + elog(ERROR, "Unable to lookup type %s", col->typename->name); + } + fktypoid[attnum++]=type; found = 1; break; } } ! if (!found) { ! List *inher; ! List *inhRelnames = stmt->inhRelnames; ! Relation rel; ! foreach(inher, inhRelnames) { ! Value *inh = lfirst(inher); ! int count; ! Assert(IsA(inh, String)); ! rel = heap_openr(strVal(inh), AccessShareLock); ! if (rel->rd_rel->relkind != RELKIND_RELATION) ! elog(ERROR, "inherited table \"%s\" is not a relation", ! strVal(inh)); ! for (count = 0; count < rel->rd_att->natts; count++) { ! char *name = NameStr(rel->rd_att->attrs[count]->attname); ! ! if (strcmp(fkattr->name, name) == 0) ! { ! fktypoid[attnum++]=rel->rd_att->attrs[count]->atttypid; ! found = 1; ! break; ! } } + heap_close(rel, NoLock); + if (found) + break; } } + if (!found) + break; } if (!found) elog(ERROR, "columns referenced in foreign key constraint not found."); } *************** *** 1228,1240 **** if (fkconstraint->fk_attrs != NIL && fkconstraint->pk_attrs == NIL) { if (strcmp(fkconstraint->pktable_name, stmt->relname) != 0) ! transformFkeyGetPrimaryKey(fkconstraint); else if (pkey != NULL) { List *pkey_attr = pkey->indexParams; List *attr; IndexElem *ielem; Ident *pkattr; foreach(attr, pkey_attr) { --- 1241,1256 ---- if (fkconstraint->fk_attrs != NIL && fkconstraint->pk_attrs == NIL) { if (strcmp(fkconstraint->pktable_name, stmt->relname) != 0) ! transformFkeyGetPrimaryKey(fkconstraint, pktypoid); else if (pkey != NULL) { List *pkey_attr = pkey->indexParams; List *attr; + List *findattr; IndexElem *ielem; Ident *pkattr; + int attnum=0; + ColumnDef *col; foreach(attr, pkey_attr) { *************** *** 1244,1249 **** --- 1260,1277 ---- pkattr->indirection = NIL; pkattr->isRel = false; fkconstraint->pk_attrs = lappend(fkconstraint->pk_attrs, pkattr); + foreach (findattr, stmt->tableElts) { + col=lfirst(findattr); + if (strcmp(col->colname, ielem->name)==0) { + char *buff=TypeNameToInternalName(col->typename); + Oid type=typenameTypeId(buff); + if (!OidIsValid(type)) { + elog(ERROR, "Unable to lookup type %s", col->typename->name); + } + pktypoid[attnum++]=type; /* need to convert typename */ + break; + } + } } } else *************** *** 1255,1261 **** else { if (strcmp(fkconstraint->pktable_name, stmt->relname) != 0) ! transformFkeyCheckAttrs(fkconstraint); else { /* Get a unique/pk constraint from above */ --- 1283,1289 ---- else { if (strcmp(fkconstraint->pktable_name, stmt->relname) != 0) ! transformFkeyCheckAttrs(fkconstraint, pktypoid); else { /* Get a unique/pk constraint from above */ *************** *** 1268,1278 **** --- 1296,1309 ---- IndexElem *indparm; List *indparms; List *pkattrs; + List *findattr; + ColumnDef *col; Ident *pkattr; if (ind->unique) { int count = 0; + int attnum=0; foreach(indparms, ind->indexParams) count++; *************** *** 1289,1295 **** indparm = lfirst(indparms); if (strcmp(indparm->name, pkattr->name) == 0) { ! found = 1; break; } } --- 1320,1362 ---- indparm = lfirst(indparms); if (strcmp(indparm->name, pkattr->name) == 0) { ! foreach (findattr, stmt->tableElts) { ! col=lfirst(findattr); ! if (strcmp(col->colname, indparm->name)==0) { ! char *buff=TypeNameToInternalName(col->typename); ! Oid type=typenameTypeId(buff); ! if (!OidIsValid(type)) { ! elog(ERROR, "Unable to lookup type %s", col->typename->name); ! } ! pktypoid[attnum++]=type; ! found=1; ! break; ! } ! } ! if (!found) { ! List *inher; ! List *inhRelnames=stmt->inhRelnames; ! Relation rel; ! foreach (inher, inhRelnames) { ! Value *inh=lfirst(inher); ! int count; ! Assert(IsA(inh, String)); ! rel=heap_openr(strVal(inh), AccessShareLock); ! if (rel->rd_rel->relkind!=RELKIND_RELATION) ! elog(ERROR, "inherited table \"%s\" is not a relation", strVal(inh)); ! for (count=0; countrd_att->natts; count++) { ! char *name=NameStr(rel->rd_att->attrs[count]->attname); ! if (strcmp(pkattr->name, name)==0) { ! pktypoid[attnum++]=rel->rd_att->attrs[count]->atttypid; ! found=1; ! break; ! } ! } ! heap_close(rel, NoLock); ! if (found) ! break; ! } ! } break; } } *************** *** 1307,1312 **** --- 1374,1389 ---- } } + for (i = 0; i < INDEX_MAX_KEYS && fktypoid[i] != 0; i++) { + /* + * fktypoid[i] is the foreign key table's i'th element's type oid + * pktypoid[i] is the primary key table's i'th element's type oid + * We let oper() do our work for us, including elog(ERROR) if the + * types don't compare with = + */ + Operator o=oper("=", fktypoid[i], pktypoid[i], false); + ReleaseSysCache(o); + } /* * Build a CREATE CONSTRAINT TRIGGER statement for the CHECK * action. *************** *** 2399,2406 **** * omitted, lookup for the definition of the primary key * */ ! if (fkconstraint->fk_attrs != NIL && fkconstraint->pk_attrs == NIL) ! transformFkeyGetPrimaryKey(fkconstraint); /* * Build a CREATE CONSTRAINT TRIGGER statement for the --- 2476,2485 ---- * omitted, lookup for the definition of the primary key * */ ! if (fkconstraint->fk_attrs != NIL && fkconstraint->pk_attrs == NIL) { ! Oid pktypoid[INDEX_MAX_KEYS]; ! transformFkeyGetPrimaryKey(fkconstraint, pktypoid); ! } /* * Build a CREATE CONSTRAINT TRIGGER statement for the *************** *** 2702,2708 **** * */ static void ! transformFkeyCheckAttrs(FkConstraint *fkconstraint) { Relation pkrel; Form_pg_attribute *pkrel_attrs; --- 2781,2787 ---- * */ static void ! transformFkeyCheckAttrs(FkConstraint *fkconstraint, Oid *pktypoid) { Relation pkrel; Form_pg_attribute *pkrel_attrs; *************** *** 2744,2749 **** --- 2823,2829 ---- if (indexStruct->indisunique) { List *attrl; + int attnum=0; for (i = 0; i < INDEX_MAX_KEYS && indexStruct->indkey[i] != 0; i++); if (i != length(fkconstraint->pk_attrs)) *************** *** 2766,2771 **** --- 2846,2852 ---- if (strcmp(name, attr->name) == 0) { + pktypoid[attnum++]=pkrel_attrs[pkattno-1]->atttypid; found = true; break; } *************** *** 2797,2803 **** * */ static void ! transformFkeyGetPrimaryKey(FkConstraint *fkconstraint) { Relation pkrel; Form_pg_attribute *pkrel_attrs; --- 2878,2884 ---- * */ static void ! transformFkeyGetPrimaryKey(FkConstraint *fkconstraint, Oid *pktypoid) { Relation pkrel; Form_pg_attribute *pkrel_attrs; *************** *** 2806,2811 **** --- 2887,2893 ---- HeapTuple indexTuple = NULL; Form_pg_index indexStruct = NULL; int i; + int attnum=0; /* * Open the referenced table and get the attributes list *************** *** 2862,2867 **** --- 2944,2950 ---- NameGetDatum(&(pkrel_attrs[pkattno - 1]->attname)))); pkattr->indirection = NIL; pkattr->isRel = false; + pktypoid[attnum++]=pkrel_attrs[pkattno-1]->atttypid; fkconstraint->pk_attrs = lappend(fkconstraint->pk_attrs, pkattr); } *** pgsql.virg/src/test/regress/sql/foreign_key.sql Tue Dec 5 11:57:55 2000 --- pgsql/src/test/regress/sql/foreign_key.sql Sun Apr 15 04:03:07 2001 *************** *** 425,427 **** --- 425,583 ---- DROP TABLE FKTABLE_FAIL1; DROP TABLE PKTABLE; + + -- + -- Tests for mismatched types + -- + -- Basic one column, two table setup + CREATE TABLE PKTABLE (ptest1 int PRIMARY KEY); + -- This next should fail, because text=int does not exist + CREATE TABLE FKTABLE (ftest1 text REFERENCES pktable); + -- This should also fail for the same reason, but here we + -- give the column name + CREATE TABLE FKTABLE (ftest1 text REFERENCES pktable(ptest1)); + -- This should succeed, even though they are different types + -- because varchar=int does exist + CREATE TABLE FKTABLE (ftest1 varchar REFERENCES pktable); + DROP TABLE FKTABLE; + -- As should this + CREATE TABLE FKTABLE (ftest1 varchar REFERENCES pktable(ptest1)); + DROP TABLE FKTABLE; + DROP TABLE PKTABLE; + + -- Two columns, two tables + CREATE TABLE PKTABLE (ptest1 int, ptest2 text, PRIMARY KEY(ptest1, ptest2)); + -- This should fail, because we just chose really odd types + CREATE TABLE FKTABLE (ftest1 cidr, ftest2 datetime, FOREIGN KEY(ftest1, ftest2) REFERENCES pktable); + -- Again, so should this... + CREATE TABLE FKTABLE (ftest1 cidr, ftest2 datetime, FOREIGN KEY(ftest1, ftest2) REFERENCES pktable(ptest1, ptest2)); + -- This fails because we mixed up the column ordering + CREATE TABLE FKTABLE (ftest1 int, ftest2 text, FOREIGN KEY(ftest2, ftest1) REFERENCES pktable); + -- As does this... + CREATE TABLE FKTABLE (ftest1 int, ftest2 text, FOREIGN KEY(ftest2, ftest1) REFERENCES pktable(ptest1, ptest2)); + -- And again.. + CREATE TABLE FKTABLE (ftest1 int, ftest2 text, FOREIGN KEY(ftest1, ftest2) REFERENCES pktable(ptest2, ptest1)); + -- This works... + CREATE TABLE FKTABLE (ftest1 int, ftest2 text, FOREIGN KEY(ftest2, ftest1) REFERENCES pktable(ptest2, ptest1)); + DROP TABLE FKTABLE; + -- As does this + CREATE TABLE FKTABLE (ftest1 int, ftest2 text, FOREIGN KEY(ftest1, ftest2) REFERENCES pktable(ptest1, ptest2)); + DROP TABLE FKTABLE; + DROP TABLE PKTABLE; + + -- Two columns, same table + -- Make sure this still works... + CREATE TABLE PKTABLE (ptest1 int, ptest2 text, ptest3 int, ptest4 text, PRIMARY KEY(ptest1, ptest2), FOREIGN KEY(ptest3, + ptest4) REFERENCES pktable(ptest1, ptest2)); + DROP TABLE PKTABLE; + -- And this, + CREATE TABLE PKTABLE (ptest1 int, ptest2 text, ptest3 int, ptest4 text, PRIMARY KEY(ptest1, ptest2), FOREIGN KEY(ptest3, + ptest4) REFERENCES pktable); + DROP TABLE PKTABLE; + -- This shouldn't (mixed up columns) + CREATE TABLE PKTABLE (ptest1 int, ptest2 text, ptest3 int, ptest4 text, PRIMARY KEY(ptest1, ptest2), FOREIGN KEY(ptest3, + ptest4) REFERENCES pktable(ptest2, ptest1)); + -- Nor should this... (same reason, we have 4,3 referencing 1,2 which mismatches types + CREATE TABLE PKTABLE (ptest1 int, ptest2 text, ptest3 int, ptest4 text, PRIMARY KEY(ptest1, ptest2), FOREIGN KEY(ptest4, + ptest3) REFERENCES pktable(ptest1, ptest2)); + -- Not this one either... Same as the last one except we didn't defined the columns being referenced. + CREATE TABLE PKTABLE (ptest1 int, ptest2 text, ptest3 int, ptest4 text, PRIMARY KEY(ptest1, ptest2), FOREIGN KEY(ptest4, + ptest3) REFERENCES pktable); + + -- + -- Now some cases with inheritance + -- Basic 2 table case: 1 column of matching types. + create table pktable_base (base1 int not null); + create table pktable (ptest1 int, primary key(base1), unique(base1, ptest1)) inherits (pktable_base); + create table fktable (ftest1 int references pktable(base1)); + -- now some ins, upd, del + insert into pktable(base1) values (1); + insert into pktable(base1) values (2); + -- let's insert a non-existant fktable value + insert into fktable(ftest1) values (3); + -- let's make a valid row for that + insert into pktable(base1) values (3); + insert into fktable(ftest1) values (3); + -- let's try removing a row that should fail from pktable + delete from pktable where base1>2; + -- okay, let's try updating all of the base1 values to *4 + -- which should fail. + update pktable set base1=base1*4; + -- okay, let's try an update that should work. + update pktable set base1=base1*4 where base1<3; + -- and a delete that should work + delete from pktable where base1>3; + -- cleanup + drop table fktable; + delete from pktable; + + -- Now 2 columns 2 tables, matching types + create table fktable (ftest1 int, ftest2 int, foreign key(ftest1, ftest2) references pktable(base1, ptest1)); + -- now some ins, upd, del + insert into pktable(base1, ptest1) values (1, 1); + insert into pktable(base1, ptest1) values (2, 2); + -- let's insert a non-existant fktable value + insert into fktable(ftest1, ftest2) values (3, 1); + -- let's make a valid row for that + insert into pktable(base1,ptest1) values (3, 1); + insert into fktable(ftest1, ftest2) values (3, 1); + -- let's try removing a row that should fail from pktable + delete from pktable where base1>2; + -- okay, let's try updating all of the base1 values to *4 + -- which should fail. + update pktable set base1=base1*4; + -- okay, let's try an update that should work. + update pktable set base1=base1*4 where base1<3; + -- and a delete that should work + delete from pktable where base1>3; + -- cleanup + drop table fktable; + drop table pktable; + drop table pktable_base; + + -- Now we'll do one all in 1 table with 2 columns of matching types + create table pktable_base(base1 int not null, base2 int); + create table pktable(ptest1 int, ptest2 int, primary key(base1, ptest1), foreign key(base2, ptest2) references + pktable(base1, ptest1)) inherits (pktable_base); + insert into pktable (base1, ptest1, base2, ptest2) values (1, 1, 1, 1); + insert into pktable (base1, ptest1, base2, ptest2) values (2, 1, 1, 1); + insert into pktable (base1, ptest1, base2, ptest2) values (2, 2, 2, 1); + insert into pktable (base1, ptest1, base2, ptest2) values (1, 3, 2, 2); + -- fails (3,2) isn't in base1, ptest1 + insert into pktable (base1, ptest1, base2, ptest2) values (2, 3, 3, 2); + -- fails (2,2) is being referenced + delete from pktable where base1=2; + -- fails (1,1) is being referenced (twice) + update pktable set base1=3 where base1=1; + -- this sequence of two deletes will work, since after the first there will be no (2,*) references + delete from pktable where base2=2; + delete from pktable where base1=2; + drop table pktable; + drop table pktable_base; + + -- 2 columns (2 tables), mismatched types + create table pktable_base(base1 int not null); + create table pktable(ptest1 text, primary key(base1, ptest1)) inherits (pktable_base); + -- just generally bad types (with and without column references on the referenced table) + create table fktable(ftest1 cidr, ftest2 int[], foreign key (ftest1, ftest2) references pktable); + create table fktable(ftest1 cidr, ftest2 int[], foreign key (ftest1, ftest2) references pktable(base1, ptest1)); + -- let's mix up which columns reference which + create table fktable(ftest1 int, ftest2 text, foreign key(ftest2, ftest1) references pktable); + create table fktable(ftest1 int, ftest2 text, foreign key(ftest2, ftest1) references pktable(base1, ptest1)); + create table fktable(ftest1 int, ftest2 text, foreign key(ftest1, ftest2) references pktable(ptest1, base1)); + drop table pktable; + drop table pktable_base; + + -- 2 columns (1 table), mismatched types + create table pktable_base(base1 int not null, base2 int); + create table pktable(ptest1 text, ptest2 text[], primary key(base1, ptest1), foreign key(base2, ptest2) references + pktable(base1, ptest1)) inherits (pktable_base); + create table pktable(ptest1 text, ptest2 text, primary key(base1, ptest1), foreign key(base2, ptest2) references + pktable(ptest1, base1)) inherits (pktable_base); + create table pktable(ptest1 text, ptest2 text, primary key(base1, ptest1), foreign key(ptest2, base2) references + pktable(base1, ptest1)) inherits (pktable_base); + create table pktable(ptest1 text, ptest2 text, primary key(base1, ptest1), foreign key(ptest2, base2) references + pktable(base1, ptest1)) inherits (pktable_base); + drop table pktable; + drop table pktable_base; + *** pgsql.virg/src/test/regress/sql/alter_table.sql Tue Dec 5 11:57:55 2000 --- pgsql/src/test/regress/sql/alter_table.sql Sun Apr 15 04:03:07 2001 *************** *** 212,214 **** --- 212,250 ---- DROP TABLE tmp2; + -- Foreign key adding test with mixed types + + CREATE TABLE PKTABLE (ptest1 int PRIMARY KEY); + CREATE TABLE FKTABLE (ftest1 text); + -- This next should fail, because text=int does not exist + ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1) references pktable; + -- This should also fail for the same reason, but here we + -- give the column name + ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1) references pktable(ptest1); + -- This should succeed, even though they are different types + -- because varchar=int does exist + DROP TABLE FKTABLE; + CREATE TABLE FKTABLE (ftest1 varchar); + ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1) references pktable; + -- As should this + ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1) references pktable(ptest1); + DROP TABLE pktable; + DROP TABLE fktable; + + CREATE TABLE PKTABLE (ptest1 int, ptest2 text, PRIMARY KEY(ptest1, ptest2)); + -- This should fail, because we just chose really odd types + CREATE TABLE FKTABLE (ftest1 cidr, ftest2 datetime); + ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1, ftest2) references pktable; + -- Again, so should this... + DROP TABLE FKTABLE; + CREATE TABLE FKTABLE (ftest1 cidr, ftest2 datetime); + ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1, ftest2) references pktable(ptest1, ptest2); + -- This fails because we mixed up the column ordering + DROP TABLE FKTABLE; + CREATE TABLE FKTABLE (ftest1 int, ftest2 text); + ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1, ftest2) references pktable(ptest2, ptest1); + -- As does this... + ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest2, ftest1) references pktable(ptest1, ptest2); + + DROP TABLE FKTABLE; + DROP TABLE PKTABLE; *** pgsql.virg/src/test/regress/expected/foreign_key.out Tue Dec 5 11:57:56 2000 --- pgsql/src/test/regress/expected/foreign_key.out Sun Apr 15 04:03:07 2001 *************** *** 712,714 **** --- 712,964 ---- DROP TABLE FKTABLE_FAIL1; ERROR: table "fktable_fail1" does not exist DROP TABLE PKTABLE; + -- + -- Tests for mismatched types + -- + -- Basic one column, two table setup + CREATE TABLE PKTABLE (ptest1 int PRIMARY KEY); + NOTICE: CREATE TABLE/PRIMARY KEY will create implicit index 'pktable_pkey' for table 'pktable' + -- This next should fail, because text=int does not exist + CREATE TABLE FKTABLE (ftest1 text REFERENCES pktable); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'text' and 'int4' + You will have to retype this query using an explicit cast + -- This should also fail for the same reason, but here we + -- give the column name + CREATE TABLE FKTABLE (ftest1 text REFERENCES pktable(ptest1)); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'text' and 'int4' + You will have to retype this query using an explicit cast + -- This should succeed, even though they are different types + -- because varchar=int does exist + CREATE TABLE FKTABLE (ftest1 varchar REFERENCES pktable); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + DROP TABLE FKTABLE; + NOTICE: DROP TABLE implicitly drops referential integrity trigger from table "pktable" + NOTICE: DROP TABLE implicitly drops referential integrity trigger from table "pktable" + -- As should this + CREATE TABLE FKTABLE (ftest1 varchar REFERENCES pktable(ptest1)); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + DROP TABLE FKTABLE; + NOTICE: DROP TABLE implicitly drops referential integrity trigger from table "pktable" + NOTICE: DROP TABLE implicitly drops referential integrity trigger from table "pktable" + DROP TABLE PKTABLE; + -- Two columns, two tables + CREATE TABLE PKTABLE (ptest1 int, ptest2 text, PRIMARY KEY(ptest1, ptest2)); + NOTICE: CREATE TABLE/PRIMARY KEY will create implicit index 'pktable_pkey' for table 'pktable' + -- This should fail, because we just chose really odd types + CREATE TABLE FKTABLE (ftest1 cidr, ftest2 datetime, FOREIGN KEY(ftest1, ftest2) REFERENCES pktable); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'cidr' and 'int4' + You will have to retype this query using an explicit cast + -- Again, so should this... + CREATE TABLE FKTABLE (ftest1 cidr, ftest2 datetime, FOREIGN KEY(ftest1, ftest2) REFERENCES pktable(ptest1, ptest2)); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'cidr' and 'int4' + You will have to retype this query using an explicit cast + -- This fails because we mixed up the column ordering + CREATE TABLE FKTABLE (ftest1 int, ftest2 text, FOREIGN KEY(ftest2, ftest1) REFERENCES pktable); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'text' and 'int4' + You will have to retype this query using an explicit cast + -- As does this... + CREATE TABLE FKTABLE (ftest1 int, ftest2 text, FOREIGN KEY(ftest2, ftest1) REFERENCES pktable(ptest1, ptest2)); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'text' and 'int4' + You will have to retype this query using an explicit cast + -- And again.. + CREATE TABLE FKTABLE (ftest1 int, ftest2 text, FOREIGN KEY(ftest1, ftest2) REFERENCES pktable(ptest2, ptest1)); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'int4' and 'text' + You will have to retype this query using an explicit cast + -- This works... + CREATE TABLE FKTABLE (ftest1 int, ftest2 text, FOREIGN KEY(ftest2, ftest1) REFERENCES pktable(ptest2, ptest1)); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + DROP TABLE FKTABLE; + NOTICE: DROP TABLE implicitly drops referential integrity trigger from table "pktable" + NOTICE: DROP TABLE implicitly drops referential integrity trigger from table "pktable" + -- As does this + CREATE TABLE FKTABLE (ftest1 int, ftest2 text, FOREIGN KEY(ftest1, ftest2) REFERENCES pktable(ptest1, ptest2)); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + DROP TABLE FKTABLE; + NOTICE: DROP TABLE implicitly drops referential integrity trigger from table "pktable" + NOTICE: DROP TABLE implicitly drops referential integrity trigger from table "pktable" + DROP TABLE PKTABLE; + -- Two columns, same table + -- Make sure this still works... + CREATE TABLE PKTABLE (ptest1 int, ptest2 text, ptest3 int, ptest4 text, PRIMARY KEY(ptest1, ptest2), FOREIGN KEY(ptest3, + ptest4) REFERENCES pktable(ptest1, ptest2)); + NOTICE: CREATE TABLE/PRIMARY KEY will create implicit index 'pktable_pkey' for table 'pktable' + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + DROP TABLE PKTABLE; + -- And this, + CREATE TABLE PKTABLE (ptest1 int, ptest2 text, ptest3 int, ptest4 text, PRIMARY KEY(ptest1, ptest2), FOREIGN KEY(ptest3, + ptest4) REFERENCES pktable); + NOTICE: CREATE TABLE/PRIMARY KEY will create implicit index 'pktable_pkey' for table 'pktable' + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + DROP TABLE PKTABLE; + -- This shouldn't (mixed up columns) + CREATE TABLE PKTABLE (ptest1 int, ptest2 text, ptest3 int, ptest4 text, PRIMARY KEY(ptest1, ptest2), FOREIGN KEY(ptest3, + ptest4) REFERENCES pktable(ptest2, ptest1)); + NOTICE: CREATE TABLE/PRIMARY KEY will create implicit index 'pktable_pkey' for table 'pktable' + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'int4' and 'text' + You will have to retype this query using an explicit cast + -- Nor should this... (same reason, we have 4,3 referencing 1,2 which mismatches types + CREATE TABLE PKTABLE (ptest1 int, ptest2 text, ptest3 int, ptest4 text, PRIMARY KEY(ptest1, ptest2), FOREIGN KEY(ptest4, + ptest3) REFERENCES pktable(ptest1, ptest2)); + NOTICE: CREATE TABLE/PRIMARY KEY will create implicit index 'pktable_pkey' for table 'pktable' + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'text' and 'int4' + You will have to retype this query using an explicit cast + -- Not this one either... Same as the last one except we didn't defined the columns being referenced. + CREATE TABLE PKTABLE (ptest1 int, ptest2 text, ptest3 int, ptest4 text, PRIMARY KEY(ptest1, ptest2), FOREIGN KEY(ptest4, + ptest3) REFERENCES pktable); + NOTICE: CREATE TABLE/PRIMARY KEY will create implicit index 'pktable_pkey' for table 'pktable' + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'text' and 'int4' + You will have to retype this query using an explicit cast + -- + -- Now some cases with inheritance + -- Basic 2 table case: 1 column of matching types. + create table pktable_base (base1 int not null); + create table pktable (ptest1 int, primary key(base1), unique(base1, ptest1)) inherits (pktable_base); + NOTICE: CREATE TABLE/PRIMARY KEY will create implicit index 'pktable_pkey' for table 'pktable' + NOTICE: CREATE TABLE/UNIQUE will create implicit index 'pktable_base1_key' for table 'pktable' + create table fktable (ftest1 int references pktable(base1)); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + -- now some ins, upd, del + insert into pktable(base1) values (1); + insert into pktable(base1) values (2); + -- let's insert a non-existant fktable value + insert into fktable(ftest1) values (3); + ERROR: referential integrity violation - key referenced from fktable not found in pktable + -- let's make a valid row for that + insert into pktable(base1) values (3); + insert into fktable(ftest1) values (3); + -- let's try removing a row that should fail from pktable + delete from pktable where base1>2; + ERROR: referential integrity violation - key in pktable still referenced from fktable + -- okay, let's try updating all of the base1 values to *4 + -- which should fail. + update pktable set base1=base1*4; + ERROR: referential integrity violation - key in pktable still referenced from fktable + -- okay, let's try an update that should work. + update pktable set base1=base1*4 where base1<3; + -- and a delete that should work + delete from pktable where base1>3; + -- cleanup + drop table fktable; + NOTICE: DROP TABLE implicitly drops referential integrity trigger from table "pktable" + NOTICE: DROP TABLE implicitly drops referential integrity trigger from table "pktable" + delete from pktable; + -- Now 2 columns 2 tables, matching types + create table fktable (ftest1 int, ftest2 int, foreign key(ftest1, ftest2) references pktable(base1, ptest1)); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + -- now some ins, upd, del + insert into pktable(base1, ptest1) values (1, 1); + insert into pktable(base1, ptest1) values (2, 2); + -- let's insert a non-existant fktable value + insert into fktable(ftest1, ftest2) values (3, 1); + ERROR: referential integrity violation - key referenced from fktable not found in pktable + -- let's make a valid row for that + insert into pktable(base1,ptest1) values (3, 1); + insert into fktable(ftest1, ftest2) values (3, 1); + -- let's try removing a row that should fail from pktable + delete from pktable where base1>2; + ERROR: referential integrity violation - key in pktable still referenced from fktable + -- okay, let's try updating all of the base1 values to *4 + -- which should fail. + update pktable set base1=base1*4; + ERROR: referential integrity violation - key in pktable still referenced from fktable + -- okay, let's try an update that should work. + update pktable set base1=base1*4 where base1<3; + -- and a delete that should work + delete from pktable where base1>3; + -- cleanup + drop table fktable; + NOTICE: DROP TABLE implicitly drops referential integrity trigger from table "pktable" + NOTICE: DROP TABLE implicitly drops referential integrity trigger from table "pktable" + drop table pktable; + drop table pktable_base; + -- Now we'll do one all in 1 table with 2 columns of matching types + create table pktable_base(base1 int not null, base2 int); + create table pktable(ptest1 int, ptest2 int, primary key(base1, ptest1), foreign key(base2, ptest2) references + pktable(base1, ptest1)) inherits (pktable_base); + NOTICE: CREATE TABLE/PRIMARY KEY will create implicit index 'pktable_pkey' for table 'pktable' + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + insert into pktable (base1, ptest1, base2, ptest2) values (1, 1, 1, 1); + insert into pktable (base1, ptest1, base2, ptest2) values (2, 1, 1, 1); + insert into pktable (base1, ptest1, base2, ptest2) values (2, 2, 2, 1); + insert into pktable (base1, ptest1, base2, ptest2) values (1, 3, 2, 2); + -- fails (3,2) isn't in base1, ptest1 + insert into pktable (base1, ptest1, base2, ptest2) values (2, 3, 3, 2); + ERROR: referential integrity violation - key referenced from pktable not found in pktable + -- fails (2,2) is being referenced + delete from pktable where base1=2; + ERROR: referential integrity violation - key in pktable still referenced from pktable + -- fails (1,1) is being referenced (twice) + update pktable set base1=3 where base1=1; + ERROR: referential integrity violation - key in pktable still referenced from pktable + -- this sequence of two deletes will work, since after the first there will be no (2,*) references + delete from pktable where base2=2; + delete from pktable where base1=2; + drop table pktable; + drop table pktable_base; + -- 2 columns (2 tables), mismatched types + create table pktable_base(base1 int not null); + create table pktable(ptest1 text, primary key(base1, ptest1)) inherits (pktable_base); + NOTICE: CREATE TABLE/PRIMARY KEY will create implicit index 'pktable_pkey' for table 'pktable' + -- just generally bad types (with and without column references on the referenced table) + create table fktable(ftest1 cidr, ftest2 int[], foreign key (ftest1, ftest2) references pktable); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'cidr' and 'int4' + You will have to retype this query using an explicit cast + create table fktable(ftest1 cidr, ftest2 int[], foreign key (ftest1, ftest2) references pktable(base1, ptest1)); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'cidr' and 'int4' + You will have to retype this query using an explicit cast + -- let's mix up which columns reference which + create table fktable(ftest1 int, ftest2 text, foreign key(ftest2, ftest1) references pktable); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'text' and 'int4' + You will have to retype this query using an explicit cast + create table fktable(ftest1 int, ftest2 text, foreign key(ftest2, ftest1) references pktable(base1, ptest1)); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'text' and 'int4' + You will have to retype this query using an explicit cast + create table fktable(ftest1 int, ftest2 text, foreign key(ftest1, ftest2) references pktable(ptest1, base1)); + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'int4' and 'text' + You will have to retype this query using an explicit cast + drop table pktable; + drop table pktable_base; + -- 2 columns (1 table), mismatched types + create table pktable_base(base1 int not null, base2 int); + create table pktable(ptest1 text, ptest2 text[], primary key(base1, ptest1), foreign key(base2, ptest2) references + pktable(base1, ptest1)) inherits (pktable_base); + NOTICE: CREATE TABLE/PRIMARY KEY will create implicit index 'pktable_pkey' for table 'pktable' + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types '_text' and 'text' + You will have to retype this query using an explicit cast + create table pktable(ptest1 text, ptest2 text, primary key(base1, ptest1), foreign key(base2, ptest2) references + pktable(ptest1, base1)) inherits (pktable_base); + NOTICE: CREATE TABLE/PRIMARY KEY will create implicit index 'pktable_pkey' for table 'pktable' + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'int4' and 'text' + You will have to retype this query using an explicit cast + create table pktable(ptest1 text, ptest2 text, primary key(base1, ptest1), foreign key(ptest2, base2) references + pktable(base1, ptest1)) inherits (pktable_base); + NOTICE: CREATE TABLE/PRIMARY KEY will create implicit index 'pktable_pkey' for table 'pktable' + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'text' and 'int4' + You will have to retype this query using an explicit cast + create table pktable(ptest1 text, ptest2 text, primary key(base1, ptest1), foreign key(ptest2, base2) references + pktable(base1, ptest1)) inherits (pktable_base); + NOTICE: CREATE TABLE/PRIMARY KEY will create implicit index 'pktable_pkey' for table 'pktable' + NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'text' and 'int4' + You will have to retype this query using an explicit cast + drop table pktable; + ERROR: table "pktable" does not exist + drop table pktable_base; *** pgsql.virg/src/test/regress/expected/alter_table.out Tue Dec 5 11:57:56 2000 --- pgsql/src/test/regress/expected/alter_table.out Sun Apr 15 04:03:07 2001 *************** *** 313,315 **** --- 313,372 ---- NOTICE: DROP TABLE implicitly drops referential integrity trigger from table "tmp2" NOTICE: DROP TABLE implicitly drops referential integrity trigger from table "tmp2" DROP TABLE tmp2; + -- Foreign key adding test with mixed types + CREATE TABLE PKTABLE (ptest1 int PRIMARY KEY); + NOTICE: CREATE TABLE/PRIMARY KEY will create implicit index 'pktable_pkey' for table 'pktable' + CREATE TABLE FKTABLE (ftest1 text); + -- This next should fail, because text=int does not exist + ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1) references pktable; + NOTICE: ALTER TABLE ... ADD CONSTRAINT will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'text' and 'int4' + You will have to retype this query using an explicit cast + -- This should also fail for the same reason, but here we + -- give the column name + ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1) references pktable(ptest1); + NOTICE: ALTER TABLE ... ADD CONSTRAINT will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'text' and 'int4' + You will have to retype this query using an explicit cast + -- This should succeed, even though they are different types + -- because varchar=int does exist + DROP TABLE FKTABLE; + CREATE TABLE FKTABLE (ftest1 varchar); + ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1) references pktable; + NOTICE: ALTER TABLE ... ADD CONSTRAINT will create implicit trigger(s) for FOREIGN KEY check(s) + -- As should this + ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1) references pktable(ptest1); + NOTICE: ALTER TABLE ... ADD CONSTRAINT will create implicit trigger(s) for FOREIGN KEY check(s) + DROP TABLE pktable; + NOTICE: DROP TABLE implicitly drops referential integrity trigger from table "fktable" + NOTICE: DROP TABLE implicitly drops referential integrity trigger from table "fktable" + DROP TABLE fktable; + CREATE TABLE PKTABLE (ptest1 int, ptest2 text, PRIMARY KEY(ptest1, ptest2)); + NOTICE: CREATE TABLE/PRIMARY KEY will create implicit index 'pktable_pkey' for table 'pktable' + -- This should fail, because we just chose really odd types + CREATE TABLE FKTABLE (ftest1 cidr, ftest2 datetime); + ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1, ftest2) references pktable; + NOTICE: ALTER TABLE ... ADD CONSTRAINT will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'cidr' and 'int4' + You will have to retype this query using an explicit cast + -- Again, so should this... + DROP TABLE FKTABLE; + CREATE TABLE FKTABLE (ftest1 cidr, ftest2 datetime); + ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1, ftest2) references pktable(ptest1, ptest2); + NOTICE: ALTER TABLE ... ADD CONSTRAINT will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'cidr' and 'int4' + You will have to retype this query using an explicit cast + -- This fails because we mixed up the column ordering + DROP TABLE FKTABLE; + CREATE TABLE FKTABLE (ftest1 int, ftest2 text); + ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1, ftest2) references pktable(ptest2, ptest1); + NOTICE: ALTER TABLE ... ADD CONSTRAINT will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'int4' and 'text' + You will have to retype this query using an explicit cast + -- As does this... + ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest2, ftest1) references pktable(ptest1, ptest2); + NOTICE: ALTER TABLE ... ADD CONSTRAINT will create implicit trigger(s) for FOREIGN KEY check(s) + ERROR: Unable to identify an operator '=' for types 'text' and 'int4' + You will have to retype this query using an explicit cast + DROP TABLE FKTABLE; + DROP TABLE PKTABLE;