#include "access/xact.h"
#include "access/sysattr.h"
+#include "catalog/pg_collation.h"
#include "catalog/pg_constraint.h"
#include "catalog/pg_operator.h"
#include "catalog/pg_type.h"
#define RIAttName(rel, attnum) NameStr(*attnumAttName(rel, attnum))
#define RIAttType(rel, attnum) attnumTypeId(rel, attnum)
+#define RIAttCollation(rel, attnum) attnumCollationId(rel, attnum)
#define RI_TRIGTYPE_INSERT 1
#define RI_TRIGTYPE_UPDATE 2
Oid opoid,
const char *rightop, Oid rightoptype);
static void ri_add_cast_to(StringInfo buf, Oid typid);
+static void ri_GenerateQualCollation(StringInfo buf, Oid collation);
static int ri_NullCheck(Relation rel, HeapTuple tup,
RI_QueryKey *key, int pairidx);
static void ri_BuildQueryKeyFull(RI_QueryKey *key,
* (fk.keycol1 IS NOT NULL [AND ...])
* For MATCH FULL:
* (fk.keycol1 IS NOT NULL [OR ...])
+ *
+ * We attach COLLATE clauses to the operators when comparing columns
+ * that have different collations.
*----------
*/
initStringInfo(&querybuf);
{
Oid pk_type = RIAttType(pk_rel, riinfo.pk_attnums[i]);
Oid fk_type = RIAttType(fk_rel, riinfo.fk_attnums[i]);
+ Oid pk_coll = RIAttCollation(pk_rel, riinfo.pk_attnums[i]);
+ Oid fk_coll = RIAttCollation(fk_rel, riinfo.fk_attnums[i]);
quoteOneName(pkattname + 3,
RIAttName(pk_rel, riinfo.pk_attnums[i]));
pkattname, pk_type,
riinfo.pf_eq_oprs[i],
fkattname, fk_type);
+ if (pk_coll != fk_coll)
+ ri_GenerateQualCollation(&querybuf, pk_coll);
sep = "AND";
}
ReleaseSysCache(typetup);
}
+/*
+ * ri_GenerateQualCollation --- add a COLLATE spec to a WHERE clause
+ *
+ * At present, we intentionally do not use this function for RI queries that
+ * compare a variable to a $n parameter. Since parameter symbols always have
+ * default collation, the effect will be to use the variable's collation.
+ * Now that is only strictly correct when testing the referenced column, since
+ * the SQL standard specifies that RI comparisons should use the referenced
+ * column's collation. However, so long as all collations have the same
+ * notion of equality (which they do, because texteq reduces to bitwise
+ * equality), there's no visible semantic impact from using the referencing
+ * column's collation when testing it, and this is a good thing to do because
+ * it lets us use a normal index on the referencing column. However, we do
+ * have to use this function when directly comparing the referencing and
+ * referenced columns, if they are of different collations; else the parser
+ * will fail to resolve the collation to use.
+ */
+static void
+ri_GenerateQualCollation(StringInfo buf, Oid collation)
+{
+ HeapTuple tp;
+ Form_pg_collation colltup;
+ char *collname;
+ char onename[MAX_QUOTED_NAME_LEN];
+
+ /* Nothing to do if it's a noncollatable data type */
+ if (!OidIsValid(collation))
+ return;
+
+ tp = SearchSysCache1(COLLOID, ObjectIdGetDatum(collation));
+ if (!HeapTupleIsValid(tp))
+ elog(ERROR, "cache lookup failed for collation %u", collation);
+ colltup = (Form_pg_collation) GETSTRUCT(tp);
+ collname = NameStr(colltup->collname);
+
+ /*
+ * We qualify the name always, for simplicity and to ensure the query
+ * is not search-path-dependent.
+ */
+ quoteOneName(onename, get_namespace_name(colltup->collnamespace));
+ appendStringInfo(buf, " COLLATE %s", onename);
+ quoteOneName(onename, collname);
+ appendStringInfo(buf, ".%s", onename);
+
+ ReleaseSysCache(tp);
+}
+
/* ----------
* ri_BuildQueryKeyFull -
*
collate_test1_idx4 | CREATE INDEX collate_test1_idx4 ON collate_test1 USING btree (((b || 'foo'::text)) COLLATE "POSIX")
(4 rows)
+-- foreign keys
+-- force indexes and mergejoins to be used for FK checking queries,
+-- else they might not exercise collation-dependent operators
+SET enable_seqscan TO 0;
+SET enable_hashjoin TO 0;
+SET enable_nestloop TO 0;
+CREATE TABLE collate_test20 (f1 text COLLATE "C" PRIMARY KEY);
+NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "collate_test20_pkey" for table "collate_test20"
+INSERT INTO collate_test20 VALUES ('foo'), ('bar');
+CREATE TABLE collate_test21 (f2 text COLLATE "POSIX" REFERENCES collate_test20);
+INSERT INTO collate_test21 VALUES ('foo'), ('bar');
+INSERT INTO collate_test21 VALUES ('baz'); -- fail
+ERROR: insert or update on table "collate_test21" violates foreign key constraint "collate_test21_f2_fkey"
+DETAIL: Key (f2)=(baz) is not present in table "collate_test20".
+CREATE TABLE collate_test22 (f2 text COLLATE "POSIX");
+INSERT INTO collate_test22 VALUES ('foo'), ('bar'), ('baz');
+ALTER TABLE collate_test22 ADD FOREIGN KEY (f2) REFERENCES collate_test20; -- fail
+ERROR: insert or update on table "collate_test22" violates foreign key constraint "collate_test22_f2_fkey"
+DETAIL: Key (f2)=(baz) is not present in table "collate_test20".
+DELETE FROM collate_test22 WHERE f2 = 'baz';
+ALTER TABLE collate_test22 ADD FOREIGN KEY (f2) REFERENCES collate_test20;
+RESET enable_seqscan;
+RESET enable_hashjoin;
+RESET enable_nestloop;
--
-- Clean up. Many of these table names will be re-used if the user is
-- trying to run any platform-specific collation tests later, so we
-- must get rid of them.
--
DROP SCHEMA collate_tests CASCADE;
-NOTICE: drop cascades to 12 other objects
+NOTICE: drop cascades to 15 other objects
DETAIL: drop cascades to table collate_test1
drop cascades to table collate_test_like
drop cascades to table collate_test2
drop cascades to view collview3
drop cascades to type testdomain
drop cascades to function dup(anyelement)
+drop cascades to table collate_test20
+drop cascades to table collate_test21
+drop cascades to table collate_test22
SELECT relname, pg_get_indexdef(oid) FROM pg_class WHERE relname LIKE 'collate_test%_idx%' ORDER BY 1;
+
+-- foreign keys
+
+-- force indexes and mergejoins to be used for FK checking queries,
+-- else they might not exercise collation-dependent operators
+SET enable_seqscan TO 0;
+SET enable_hashjoin TO 0;
+SET enable_nestloop TO 0;
+
+CREATE TABLE collate_test20 (f1 text COLLATE "C" PRIMARY KEY);
+INSERT INTO collate_test20 VALUES ('foo'), ('bar');
+CREATE TABLE collate_test21 (f2 text COLLATE "POSIX" REFERENCES collate_test20);
+INSERT INTO collate_test21 VALUES ('foo'), ('bar');
+INSERT INTO collate_test21 VALUES ('baz'); -- fail
+CREATE TABLE collate_test22 (f2 text COLLATE "POSIX");
+INSERT INTO collate_test22 VALUES ('foo'), ('bar'), ('baz');
+ALTER TABLE collate_test22 ADD FOREIGN KEY (f2) REFERENCES collate_test20; -- fail
+DELETE FROM collate_test22 WHERE f2 = 'baz';
+ALTER TABLE collate_test22 ADD FOREIGN KEY (f2) REFERENCES collate_test20;
+
+RESET enable_seqscan;
+RESET enable_hashjoin;
+RESET enable_nestloop;
+
--
-- Clean up. Many of these table names will be re-used if the user is
-- trying to run any platform-specific collation tests later, so we