1/*
2 * This test is for ICU collations.
3 */
4
5SET client_encoding TO UTF8;
6
7CREATE SCHEMA collate_tests;
8SET search_path = collate_tests;
9
10
11CREATE TABLE collate_test1 (
12    a int,
13    b text COLLATE "en-x-icu" NOT NULL
14);
15
16\d collate_test1
17
18CREATE TABLE collate_test_fail (
19    a int,
20    b text COLLATE "ja_JP.eucjp-x-icu"
21);
22
23CREATE TABLE collate_test_fail (
24    a int,
25    b text COLLATE "foo-x-icu"
26);
27
28CREATE TABLE collate_test_fail (
29    a int COLLATE "en-x-icu",
30    b text
31);
32
33CREATE TABLE collate_test_like (
34    LIKE collate_test1
35);
36
37\d collate_test_like
38
39CREATE TABLE collate_test2 (
40    a int,
41    b text COLLATE "sv-x-icu"
42);
43
44CREATE TABLE collate_test3 (
45    a int,
46    b text COLLATE "C"
47);
48
49INSERT INTO collate_test1 VALUES (1, 'abc'), (2, 'äbc'), (3, 'bbc'), (4, 'ABC');
50INSERT INTO collate_test2 SELECT * FROM collate_test1;
51INSERT INTO collate_test3 SELECT * FROM collate_test1;
52
53SELECT * FROM collate_test1 WHERE b >= 'bbc';
54SELECT * FROM collate_test2 WHERE b >= 'bbc';
55SELECT * FROM collate_test3 WHERE b >= 'bbc';
56SELECT * FROM collate_test3 WHERE b >= 'BBC';
57
58SELECT * FROM collate_test1 WHERE b COLLATE "C" >= 'bbc';
59SELECT * FROM collate_test1 WHERE b >= 'bbc' COLLATE "C";
60SELECT * FROM collate_test1 WHERE b COLLATE "C" >= 'bbc' COLLATE "C";
61SELECT * FROM collate_test1 WHERE b COLLATE "C" >= 'bbc' COLLATE "en-x-icu";
62
63
64CREATE DOMAIN testdomain_sv AS text COLLATE "sv-x-icu";
65CREATE DOMAIN testdomain_i AS int COLLATE "sv-x-icu"; -- fails
66CREATE TABLE collate_test4 (
67    a int,
68    b testdomain_sv
69);
70INSERT INTO collate_test4 SELECT * FROM collate_test1;
71SELECT a, b FROM collate_test4 ORDER BY b;
72
73CREATE TABLE collate_test5 (
74    a int,
75    b testdomain_sv COLLATE "en-x-icu"
76);
77INSERT INTO collate_test5 SELECT * FROM collate_test1;
78SELECT a, b FROM collate_test5 ORDER BY b;
79
80
81SELECT a, b FROM collate_test1 ORDER BY b;
82SELECT a, b FROM collate_test2 ORDER BY b;
83SELECT a, b FROM collate_test3 ORDER BY b;
84
85SELECT a, b FROM collate_test1 ORDER BY b COLLATE "C";
86
87-- star expansion
88SELECT * FROM collate_test1 ORDER BY b;
89SELECT * FROM collate_test2 ORDER BY b;
90SELECT * FROM collate_test3 ORDER BY b;
91
92-- constant expression folding
93SELECT 'bbc' COLLATE "en-x-icu" > 'äbc' COLLATE "en-x-icu" AS "true";
94SELECT 'bbc' COLLATE "sv-x-icu" > 'äbc' COLLATE "sv-x-icu" AS "false";
95
96-- upper/lower
97
98CREATE TABLE collate_test10 (
99    a int,
100    x text COLLATE "en-x-icu",
101    y text COLLATE "tr-x-icu"
102);
103
104INSERT INTO collate_test10 VALUES (1, 'hij', 'hij'), (2, 'HIJ', 'HIJ');
105
106SELECT a, lower(x), lower(y), upper(x), upper(y), initcap(x), initcap(y) FROM collate_test10;
107SELECT a, lower(x COLLATE "C"), lower(y COLLATE "C") FROM collate_test10;
108
109SELECT a, x, y FROM collate_test10 ORDER BY lower(y), a;
110
111-- LIKE/ILIKE
112
113SELECT * FROM collate_test1 WHERE b LIKE 'abc';
114SELECT * FROM collate_test1 WHERE b LIKE 'abc%';
115SELECT * FROM collate_test1 WHERE b LIKE '%bc%';
116SELECT * FROM collate_test1 WHERE b ILIKE 'abc';
117SELECT * FROM collate_test1 WHERE b ILIKE 'abc%';
118SELECT * FROM collate_test1 WHERE b ILIKE '%bc%';
119
120SELECT 'Türkiye' COLLATE "en-x-icu" ILIKE '%KI%' AS "true";
121SELECT 'Türkiye' COLLATE "tr-x-icu" ILIKE '%KI%' AS "false";
122
123SELECT 'bıt' ILIKE 'BIT' COLLATE "en-x-icu" AS "false";
124SELECT 'bıt' ILIKE 'BIT' COLLATE "tr-x-icu" AS "true";
125
126-- The following actually exercises the selectivity estimation for ILIKE.
127SELECT relname FROM pg_class WHERE relname ILIKE 'abc%';
128
129-- regular expressions
130
131SELECT * FROM collate_test1 WHERE b ~ '^abc$';
132SELECT * FROM collate_test1 WHERE b ~ '^abc';
133SELECT * FROM collate_test1 WHERE b ~ 'bc';
134SELECT * FROM collate_test1 WHERE b ~* '^abc$';
135SELECT * FROM collate_test1 WHERE b ~* '^abc';
136SELECT * FROM collate_test1 WHERE b ~* 'bc';
137
138CREATE TABLE collate_test6 (
139    a int,
140    b text COLLATE "en-x-icu"
141);
142INSERT INTO collate_test6 VALUES (1, 'abc'), (2, 'ABC'), (3, '123'), (4, 'ab1'),
143                                 (5, 'a1!'), (6, 'a c'), (7, '!.;'), (8, '   '),
144                                 (9, 'äbç'), (10, 'ÄBÇ');
145SELECT b,
146       b ~ '^[[:alpha:]]+$' AS is_alpha,
147       b ~ '^[[:upper:]]+$' AS is_upper,
148       b ~ '^[[:lower:]]+$' AS is_lower,
149       b ~ '^[[:digit:]]+$' AS is_digit,
150       b ~ '^[[:alnum:]]+$' AS is_alnum,
151       b ~ '^[[:graph:]]+$' AS is_graph,
152       b ~ '^[[:print:]]+$' AS is_print,
153       b ~ '^[[:punct:]]+$' AS is_punct,
154       b ~ '^[[:space:]]+$' AS is_space
155FROM collate_test6;
156
157SELECT 'Türkiye' COLLATE "en-x-icu" ~* 'KI' AS "true";
158SELECT 'Türkiye' COLLATE "tr-x-icu" ~* 'KI' AS "true";  -- true with ICU
159
160SELECT 'bıt' ~* 'BIT' COLLATE "en-x-icu" AS "false";
161SELECT 'bıt' ~* 'BIT' COLLATE "tr-x-icu" AS "false";  -- false with ICU
162
163-- The following actually exercises the selectivity estimation for ~*.
164SELECT relname FROM pg_class WHERE relname ~* '^abc';
165
166
167/* not run by default because it requires tr_TR system locale
168-- to_char
169
170SET lc_time TO 'tr_TR';
171SELECT to_char(date '2010-04-01', 'DD TMMON YYYY');
172SELECT to_char(date '2010-04-01', 'DD TMMON YYYY' COLLATE "tr-x-icu");
173*/
174
175
176-- backwards parsing
177
178CREATE VIEW collview1 AS SELECT * FROM collate_test1 WHERE b COLLATE "C" >= 'bbc';
179CREATE VIEW collview2 AS SELECT a, b FROM collate_test1 ORDER BY b COLLATE "C";
180CREATE VIEW collview3 AS SELECT a, lower((x || x) COLLATE "C") FROM collate_test10;
181
182SELECT table_name, view_definition FROM information_schema.views
183  WHERE table_name LIKE 'collview%' ORDER BY 1;
184
185
186-- collation propagation in various expression types
187
188SELECT a, coalesce(b, 'foo') FROM collate_test1 ORDER BY 2;
189SELECT a, coalesce(b, 'foo') FROM collate_test2 ORDER BY 2;
190SELECT a, coalesce(b, 'foo') FROM collate_test3 ORDER BY 2;
191SELECT a, lower(coalesce(x, 'foo')), lower(coalesce(y, 'foo')) FROM collate_test10;
192
193SELECT a, b, greatest(b, 'CCC') FROM collate_test1 ORDER BY 3;
194SELECT a, b, greatest(b, 'CCC') FROM collate_test2 ORDER BY 3;
195SELECT a, b, greatest(b, 'CCC') FROM collate_test3 ORDER BY 3;
196SELECT a, x, y, lower(greatest(x, 'foo')), lower(greatest(y, 'foo')) FROM collate_test10;
197
198SELECT a, nullif(b, 'abc') FROM collate_test1 ORDER BY 2;
199SELECT a, nullif(b, 'abc') FROM collate_test2 ORDER BY 2;
200SELECT a, nullif(b, 'abc') FROM collate_test3 ORDER BY 2;
201SELECT a, lower(nullif(x, 'foo')), lower(nullif(y, 'foo')) FROM collate_test10;
202
203SELECT a, CASE b WHEN 'abc' THEN 'abcd' ELSE b END FROM collate_test1 ORDER BY 2;
204SELECT a, CASE b WHEN 'abc' THEN 'abcd' ELSE b END FROM collate_test2 ORDER BY 2;
205SELECT a, CASE b WHEN 'abc' THEN 'abcd' ELSE b END FROM collate_test3 ORDER BY 2;
206
207CREATE DOMAIN testdomain AS text;
208SELECT a, b::testdomain FROM collate_test1 ORDER BY 2;
209SELECT a, b::testdomain FROM collate_test2 ORDER BY 2;
210SELECT a, b::testdomain FROM collate_test3 ORDER BY 2;
211SELECT a, b::testdomain_sv FROM collate_test3 ORDER BY 2;
212SELECT a, lower(x::testdomain), lower(y::testdomain) FROM collate_test10;
213
214SELECT min(b), max(b) FROM collate_test1;
215SELECT min(b), max(b) FROM collate_test2;
216SELECT min(b), max(b) FROM collate_test3;
217
218SELECT array_agg(b ORDER BY b) FROM collate_test1;
219SELECT array_agg(b ORDER BY b) FROM collate_test2;
220SELECT array_agg(b ORDER BY b) FROM collate_test3;
221
222SELECT a, b FROM collate_test1 UNION ALL SELECT a, b FROM collate_test1 ORDER BY 2;
223SELECT a, b FROM collate_test2 UNION SELECT a, b FROM collate_test2 ORDER BY 2;
224SELECT a, b FROM collate_test3 WHERE a < 4 INTERSECT SELECT a, b FROM collate_test3 WHERE a > 1 ORDER BY 2;
225SELECT a, b FROM collate_test3 EXCEPT SELECT a, b FROM collate_test3 WHERE a < 2 ORDER BY 2;
226
227SELECT a, b FROM collate_test1 UNION ALL SELECT a, b FROM collate_test3 ORDER BY 2; -- fail
228SELECT a, b FROM collate_test1 UNION ALL SELECT a, b FROM collate_test3; -- ok
229SELECT a, b FROM collate_test1 UNION SELECT a, b FROM collate_test3 ORDER BY 2; -- fail
230SELECT a, b COLLATE "C" FROM collate_test1 UNION SELECT a, b FROM collate_test3 ORDER BY 2; -- ok
231SELECT a, b FROM collate_test1 INTERSECT SELECT a, b FROM collate_test3 ORDER BY 2; -- fail
232SELECT a, b FROM collate_test1 EXCEPT SELECT a, b FROM collate_test3 ORDER BY 2; -- fail
233
234CREATE TABLE test_u AS SELECT a, b FROM collate_test1 UNION ALL SELECT a, b FROM collate_test3; -- fail
235
236-- ideally this would be a parse-time error, but for now it must be run-time:
237select x < y from collate_test10; -- fail
238select x || y from collate_test10; -- ok, because || is not collation aware
239select x, y from collate_test10 order by x || y; -- not so ok
240
241-- collation mismatch between recursive and non-recursive term
242WITH RECURSIVE foo(x) AS
243   (SELECT x FROM (VALUES('a' COLLATE "en-x-icu"),('b')) t(x)
244   UNION ALL
245   SELECT (x || 'c') COLLATE "de-x-icu" FROM foo WHERE length(x) < 10)
246SELECT * FROM foo;
247
248
249-- casting
250
251SELECT CAST('42' AS text COLLATE "C");
252
253SELECT a, CAST(b AS varchar) FROM collate_test1 ORDER BY 2;
254SELECT a, CAST(b AS varchar) FROM collate_test2 ORDER BY 2;
255SELECT a, CAST(b AS varchar) FROM collate_test3 ORDER BY 2;
256
257
258-- propagation of collation in SQL functions (inlined and non-inlined cases)
259-- and plpgsql functions too
260
261CREATE FUNCTION mylt (text, text) RETURNS boolean LANGUAGE sql
262    AS $$ select $1 < $2 $$;
263
264CREATE FUNCTION mylt_noninline (text, text) RETURNS boolean LANGUAGE sql
265    AS $$ select $1 < $2 limit 1 $$;
266
267CREATE FUNCTION mylt_plpgsql (text, text) RETURNS boolean LANGUAGE plpgsql
268    AS $$ begin return $1 < $2; end $$;
269
270SELECT a.b AS a, b.b AS b, a.b < b.b AS lt,
271       mylt(a.b, b.b), mylt_noninline(a.b, b.b), mylt_plpgsql(a.b, b.b)
272FROM collate_test1 a, collate_test1 b
273ORDER BY a.b, b.b;
274
275SELECT a.b AS a, b.b AS b, a.b < b.b COLLATE "C" AS lt,
276       mylt(a.b, b.b COLLATE "C"), mylt_noninline(a.b, b.b COLLATE "C"),
277       mylt_plpgsql(a.b, b.b COLLATE "C")
278FROM collate_test1 a, collate_test1 b
279ORDER BY a.b, b.b;
280
281
282-- collation override in plpgsql
283
284CREATE FUNCTION mylt2 (x text, y text) RETURNS boolean LANGUAGE plpgsql AS $$
285declare
286  xx text := x;
287  yy text := y;
288begin
289  return xx < yy;
290end
291$$;
292
293SELECT mylt2('a', 'B' collate "en-x-icu") as t, mylt2('a', 'B' collate "C") as f;
294
295CREATE OR REPLACE FUNCTION
296  mylt2 (x text, y text) RETURNS boolean LANGUAGE plpgsql AS $$
297declare
298  xx text COLLATE "POSIX" := x;
299  yy text := y;
300begin
301  return xx < yy;
302end
303$$;
304
305SELECT mylt2('a', 'B') as f;
306SELECT mylt2('a', 'B' collate "C") as fail; -- conflicting collations
307SELECT mylt2('a', 'B' collate "POSIX") as f;
308
309
310-- polymorphism
311
312SELECT * FROM unnest((SELECT array_agg(b ORDER BY b) FROM collate_test1)) ORDER BY 1;
313SELECT * FROM unnest((SELECT array_agg(b ORDER BY b) FROM collate_test2)) ORDER BY 1;
314SELECT * FROM unnest((SELECT array_agg(b ORDER BY b) FROM collate_test3)) ORDER BY 1;
315
316CREATE FUNCTION dup (anyelement) RETURNS anyelement
317    AS 'select $1' LANGUAGE sql;
318
319SELECT a, dup(b) FROM collate_test1 ORDER BY 2;
320SELECT a, dup(b) FROM collate_test2 ORDER BY 2;
321SELECT a, dup(b) FROM collate_test3 ORDER BY 2;
322
323
324-- indexes
325
326CREATE INDEX collate_test1_idx1 ON collate_test1 (b);
327CREATE INDEX collate_test1_idx2 ON collate_test1 (b COLLATE "C");
328CREATE INDEX collate_test1_idx3 ON collate_test1 ((b COLLATE "C")); -- this is different grammatically
329CREATE INDEX collate_test1_idx4 ON collate_test1 (((b||'foo') COLLATE "POSIX"));
330
331CREATE INDEX collate_test1_idx5 ON collate_test1 (a COLLATE "C"); -- fail
332CREATE INDEX collate_test1_idx6 ON collate_test1 ((a COLLATE "C")); -- fail
333
334SELECT relname, pg_get_indexdef(oid) FROM pg_class WHERE relname LIKE 'collate_test%_idx%' ORDER BY 1;
335
336
337-- schema manipulation commands
338
339CREATE ROLE regress_test_role;
340CREATE SCHEMA test_schema;
341
342-- We need to do this this way to cope with varying names for encodings:
343do $$
344BEGIN
345  EXECUTE 'CREATE COLLATION test0 (provider = icu, locale = ' ||
346          quote_literal(current_setting('lc_collate')) || ');';
347END
348$$;
349CREATE COLLATION test0 FROM "C"; -- fail, duplicate name
350do $$
351BEGIN
352  EXECUTE 'CREATE COLLATION test1 (provider = icu, lc_collate = ' ||
353          quote_literal(current_setting('lc_collate')) ||
354          ', lc_ctype = ' ||
355          quote_literal(current_setting('lc_ctype')) || ');';
356END
357$$;
358CREATE COLLATION test3 (provider = icu, lc_collate = 'en_US.utf8'); -- fail, need lc_ctype
359CREATE COLLATION testx (provider = icu, locale = 'nonsense'); /* never fails with ICU */  DROP COLLATION testx;
360
361CREATE COLLATION test4 FROM nonsense;
362CREATE COLLATION test5 FROM test0;
363
364SELECT collname FROM pg_collation WHERE collname LIKE 'test%' ORDER BY 1;
365
366ALTER COLLATION test1 RENAME TO test11;
367ALTER COLLATION test0 RENAME TO test11; -- fail
368ALTER COLLATION test1 RENAME TO test22; -- fail
369
370ALTER COLLATION test11 OWNER TO regress_test_role;
371ALTER COLLATION test11 OWNER TO nonsense;
372ALTER COLLATION test11 SET SCHEMA test_schema;
373
374COMMENT ON COLLATION test0 IS 'US English';
375
376SELECT collname, nspname, obj_description(pg_collation.oid, 'pg_collation')
377    FROM pg_collation JOIN pg_namespace ON (collnamespace = pg_namespace.oid)
378    WHERE collname LIKE 'test%'
379    ORDER BY 1;
380
381DROP COLLATION test0, test_schema.test11, test5;
382DROP COLLATION test0; -- fail
383DROP COLLATION IF EXISTS test0;
384
385SELECT collname FROM pg_collation WHERE collname LIKE 'test%';
386
387DROP SCHEMA test_schema;
388DROP ROLE regress_test_role;
389
390
391-- ALTER
392
393ALTER COLLATION "en-x-icu" REFRESH VERSION;
394
395
396-- dependencies
397
398CREATE COLLATION test0 FROM "C";
399
400CREATE TABLE collate_dep_test1 (a int, b text COLLATE test0);
401CREATE DOMAIN collate_dep_dom1 AS text COLLATE test0;
402CREATE TYPE collate_dep_test2 AS (x int, y text COLLATE test0);
403CREATE VIEW collate_dep_test3 AS SELECT text 'foo' COLLATE test0 AS foo;
404CREATE TABLE collate_dep_test4t (a int, b text);
405CREATE INDEX collate_dep_test4i ON collate_dep_test4t (b COLLATE test0);
406
407DROP COLLATION test0 RESTRICT; -- fail
408DROP COLLATION test0 CASCADE;
409
410\d collate_dep_test1
411\d collate_dep_test2
412
413DROP TABLE collate_dep_test1, collate_dep_test4t;
414DROP TYPE collate_dep_test2;
415
416-- test range types and collations
417
418create type textrange_c as range(subtype=text, collation="C");
419create type textrange_en_us as range(subtype=text, collation="en-x-icu");
420
421select textrange_c('A','Z') @> 'b'::text;
422select textrange_en_us('A','Z') @> 'b'::text;
423
424drop type textrange_c;
425drop type textrange_en_us;
426
427
428-- test ICU collation customization
429
430-- test the attributes handled by icu_set_collation_attributes()
431
432CREATE COLLATION testcoll_ignore_accents (provider = icu, locale = '@colStrength=primary;colCaseLevel=yes');
433SELECT 'aaá' > 'AAA' COLLATE "und-x-icu", 'aaá' < 'AAA' COLLATE testcoll_ignore_accents;
434
435CREATE COLLATION testcoll_backwards (provider = icu, locale = '@colBackwards=yes');
436SELECT 'coté' < 'côte' COLLATE "und-x-icu", 'coté' > 'côte' COLLATE testcoll_backwards;
437
438CREATE COLLATION testcoll_lower_first (provider = icu, locale = '@colCaseFirst=lower');
439CREATE COLLATION testcoll_upper_first (provider = icu, locale = '@colCaseFirst=upper');
440SELECT 'aaa' < 'AAA' COLLATE testcoll_lower_first, 'aaa' > 'AAA' COLLATE testcoll_upper_first;
441
442CREATE COLLATION testcoll_shifted (provider = icu, locale = '@colAlternate=shifted');
443SELECT 'de-luge' < 'deanza' COLLATE "und-x-icu", 'de-luge' > 'deanza' COLLATE testcoll_shifted;
444
445CREATE COLLATION testcoll_numeric (provider = icu, locale = '@colNumeric=yes');
446SELECT 'A-21' > 'A-123' COLLATE "und-x-icu", 'A-21' < 'A-123' COLLATE testcoll_numeric;
447
448CREATE COLLATION testcoll_error1 (provider = icu, locale = '@colNumeric=lower');
449
450-- test that attributes not handled by icu_set_collation_attributes()
451-- (handled by ucol_open() directly) also work
452CREATE COLLATION testcoll_de_phonebook (provider = icu, locale = 'de@collation=phonebook');
453SELECT 'Goldmann' < 'Götz' COLLATE "de-x-icu", 'Goldmann' > 'Götz' COLLATE testcoll_de_phonebook;
454
455
456-- nondeterministic collations
457
458CREATE COLLATION ctest_det (provider = icu, locale = '', deterministic = true);
459CREATE COLLATION ctest_nondet (provider = icu, locale = '', deterministic = false);
460
461CREATE TABLE test6 (a int, b text);
462-- same string in different normal forms
463INSERT INTO test6 VALUES (1, U&'\00E4bc');
464INSERT INTO test6 VALUES (2, U&'\0061\0308bc');
465SELECT * FROM test6;
466SELECT * FROM test6 WHERE b = 'äbc' COLLATE ctest_det;
467SELECT * FROM test6 WHERE b = 'äbc' COLLATE ctest_nondet;
468
469CREATE COLLATION case_sensitive (provider = icu, locale = '');
470CREATE COLLATION case_insensitive (provider = icu, locale = '@colStrength=secondary', deterministic = false);
471
472SELECT 'abc' <= 'ABC' COLLATE case_sensitive, 'abc' >= 'ABC' COLLATE case_sensitive;
473SELECT 'abc' <= 'ABC' COLLATE case_insensitive, 'abc' >= 'ABC' COLLATE case_insensitive;
474
475CREATE TABLE test1cs (x text COLLATE case_sensitive);
476CREATE TABLE test2cs (x text COLLATE case_sensitive);
477CREATE TABLE test3cs (x text COLLATE case_sensitive);
478INSERT INTO test1cs VALUES ('abc'), ('def'), ('ghi');
479INSERT INTO test2cs VALUES ('ABC'), ('ghi');
480INSERT INTO test3cs VALUES ('abc'), ('ABC'), ('def'), ('ghi');
481
482SELECT x FROM test3cs WHERE x = 'abc';
483SELECT x FROM test3cs WHERE x <> 'abc';
484SELECT x FROM test3cs WHERE x LIKE 'a%';
485SELECT x FROM test3cs WHERE x ILIKE 'a%';
486SELECT x FROM test3cs WHERE x SIMILAR TO 'a%';
487SELECT x FROM test3cs WHERE x ~ 'a';
488SELECT x FROM test1cs UNION SELECT x FROM test2cs ORDER BY x;
489SELECT x FROM test2cs UNION SELECT x FROM test1cs ORDER BY x;
490SELECT x FROM test1cs INTERSECT SELECT x FROM test2cs;
491SELECT x FROM test2cs INTERSECT SELECT x FROM test1cs;
492SELECT x FROM test1cs EXCEPT SELECT x FROM test2cs;
493SELECT x FROM test2cs EXCEPT SELECT x FROM test1cs;
494SELECT DISTINCT x FROM test3cs ORDER BY x;
495SELECT count(DISTINCT x) FROM test3cs;
496SELECT x, count(*) FROM test3cs GROUP BY x ORDER BY x;
497SELECT x, row_number() OVER (ORDER BY x), rank() OVER (ORDER BY x) FROM test3cs ORDER BY x;
498CREATE UNIQUE INDEX ON test1cs (x);  -- ok
499INSERT INTO test1cs VALUES ('ABC');  -- ok
500CREATE UNIQUE INDEX ON test3cs (x);  -- ok
501SELECT string_to_array('ABC,DEF,GHI' COLLATE case_sensitive, ',', 'abc');
502SELECT string_to_array('ABCDEFGHI' COLLATE case_sensitive, NULL, 'b');
503
504CREATE TABLE test1ci (x text COLLATE case_insensitive);
505CREATE TABLE test2ci (x text COLLATE case_insensitive);
506CREATE TABLE test3ci (x text COLLATE case_insensitive);
507CREATE INDEX ON test3ci (x text_pattern_ops);  -- error
508INSERT INTO test1ci VALUES ('abc'), ('def'), ('ghi');
509INSERT INTO test2ci VALUES ('ABC'), ('ghi');
510INSERT INTO test3ci VALUES ('abc'), ('ABC'), ('def'), ('ghi');
511
512SELECT x FROM test3ci WHERE x = 'abc';
513SELECT x FROM test3ci WHERE x <> 'abc';
514SELECT x FROM test3ci WHERE x LIKE 'a%';
515SELECT x FROM test3ci WHERE x ILIKE 'a%';
516SELECT x FROM test3ci WHERE x SIMILAR TO 'a%';
517SELECT x FROM test3ci WHERE x ~ 'a';
518SELECT x FROM test1ci UNION SELECT x FROM test2ci ORDER BY x;
519SELECT x FROM test2ci UNION SELECT x FROM test1ci ORDER BY x;
520SELECT x FROM test1ci INTERSECT SELECT x FROM test2ci ORDER BY x;
521SELECT x FROM test2ci INTERSECT SELECT x FROM test1ci ORDER BY x;
522SELECT x FROM test1ci EXCEPT SELECT x FROM test2ci;
523SELECT x FROM test2ci EXCEPT SELECT x FROM test1ci;
524SELECT DISTINCT x FROM test3ci ORDER BY x;
525SELECT count(DISTINCT x) FROM test3ci;
526SELECT x, count(*) FROM test3ci GROUP BY x ORDER BY x;
527SELECT x, row_number() OVER (ORDER BY x), rank() OVER (ORDER BY x) FROM test3ci ORDER BY x;
528CREATE UNIQUE INDEX ON test1ci (x);  -- ok
529INSERT INTO test1ci VALUES ('ABC');  -- error
530CREATE UNIQUE INDEX ON test3ci (x);  -- error
531SELECT string_to_array('ABC,DEF,GHI' COLLATE case_insensitive, ',', 'abc');
532SELECT string_to_array('ABCDEFGHI' COLLATE case_insensitive, NULL, 'b');
533
534-- bpchar
535CREATE TABLE test1bpci (x char(3) COLLATE case_insensitive);
536CREATE TABLE test2bpci (x char(3) COLLATE case_insensitive);
537CREATE TABLE test3bpci (x char(3) COLLATE case_insensitive);
538CREATE INDEX ON test3bpci (x bpchar_pattern_ops);  -- error
539INSERT INTO test1bpci VALUES ('abc'), ('def'), ('ghi');
540INSERT INTO test2bpci VALUES ('ABC'), ('ghi');
541INSERT INTO test3bpci VALUES ('abc'), ('ABC'), ('def'), ('ghi');
542
543SELECT x FROM test3bpci WHERE x = 'abc';
544SELECT x FROM test3bpci WHERE x <> 'abc';
545SELECT x FROM test3bpci WHERE x LIKE 'a%';
546SELECT x FROM test3bpci WHERE x ILIKE 'a%';
547SELECT x FROM test3bpci WHERE x SIMILAR TO 'a%';
548SELECT x FROM test3bpci WHERE x ~ 'a';
549SELECT x FROM test1bpci UNION SELECT x FROM test2bpci ORDER BY x;
550SELECT x FROM test2bpci UNION SELECT x FROM test1bpci ORDER BY x;
551SELECT x FROM test1bpci INTERSECT SELECT x FROM test2bpci ORDER BY x;
552SELECT x FROM test2bpci INTERSECT SELECT x FROM test1bpci ORDER BY x;
553SELECT x FROM test1bpci EXCEPT SELECT x FROM test2bpci;
554SELECT x FROM test2bpci EXCEPT SELECT x FROM test1bpci;
555SELECT DISTINCT x FROM test3bpci ORDER BY x;
556SELECT count(DISTINCT x) FROM test3bpci;
557SELECT x, count(*) FROM test3bpci GROUP BY x ORDER BY x;
558SELECT x, row_number() OVER (ORDER BY x), rank() OVER (ORDER BY x) FROM test3bpci ORDER BY x;
559CREATE UNIQUE INDEX ON test1bpci (x);  -- ok
560INSERT INTO test1bpci VALUES ('ABC');  -- error
561CREATE UNIQUE INDEX ON test3bpci (x);  -- error
562SELECT string_to_array('ABC,DEF,GHI'::char(11) COLLATE case_insensitive, ',', 'abc');
563SELECT string_to_array('ABCDEFGHI'::char(9) COLLATE case_insensitive, NULL, 'b');
564
565-- This tests the issue described in match_pattern_prefix().  In the
566-- absence of that check, the case_insensitive tests below would
567-- return no rows where they should logically return one.
568CREATE TABLE test4c (x text COLLATE "C");
569INSERT INTO test4c VALUES ('abc');
570CREATE INDEX ON test4c (x);
571SET enable_seqscan = off;
572SELECT x FROM test4c WHERE x LIKE 'ABC' COLLATE case_sensitive;  -- ok, no rows
573SELECT x FROM test4c WHERE x LIKE 'ABC%' COLLATE case_sensitive;  -- ok, no rows
574SELECT x FROM test4c WHERE x LIKE 'ABC' COLLATE case_insensitive;  -- error
575SELECT x FROM test4c WHERE x LIKE 'ABC%' COLLATE case_insensitive;  -- error
576RESET enable_seqscan;
577
578-- Unicode special case: different variants of Greek lower case sigma.
579-- A naive implementation like citext that just does lower(x) =
580-- lower(y) will do the wrong thing here, because lower('Σ') is 'σ'
581-- but upper('ς') is 'Σ'.
582SELECT 'ὀδυσσεύς' = 'ὈΔΥΣΣΕΎΣ' COLLATE case_sensitive;
583SELECT 'ὀδυσσεύς' = 'ὈΔΥΣΣΕΎΣ' COLLATE case_insensitive;
584
585-- name vs. text comparison operators
586SELECT relname FROM pg_class WHERE relname = 'PG_CLASS'::text COLLATE case_insensitive;
587SELECT relname FROM pg_class WHERE 'PG_CLASS'::text = relname COLLATE case_insensitive;
588
589SELECT typname FROM pg_type WHERE typname LIKE 'int_' AND typname <> 'INT2'::text COLLATE case_insensitive;
590SELECT typname FROM pg_type WHERE typname LIKE 'int_' AND 'INT2'::text <> typname COLLATE case_insensitive;;
591
592-- test case adapted from subselect.sql
593CREATE TEMP TABLE outer_text (f1 text COLLATE case_insensitive, f2 text);
594INSERT INTO outer_text VALUES ('a', 'a');
595INSERT INTO outer_text VALUES ('b', 'a');
596INSERT INTO outer_text VALUES ('A', NULL);
597INSERT INTO outer_text VALUES ('B', NULL);
598
599CREATE TEMP TABLE inner_text (c1 text COLLATE case_insensitive, c2 text);
600INSERT INTO inner_text VALUES ('a', NULL);
601
602SELECT * FROM outer_text WHERE (f1, f2) NOT IN (SELECT * FROM inner_text);
603
604-- accents
605CREATE COLLATION ignore_accents (provider = icu, locale = '@colStrength=primary;colCaseLevel=yes', deterministic = false);
606
607CREATE TABLE test4 (a int, b text);
608INSERT INTO test4 VALUES (1, 'cote'), (2, 'côte'), (3, 'coté'), (4, 'côté');
609SELECT * FROM test4 WHERE b = 'cote';
610SELECT * FROM test4 WHERE b = 'cote' COLLATE ignore_accents;
611SELECT * FROM test4 WHERE b = 'Cote' COLLATE ignore_accents;  -- still case-sensitive
612SELECT * FROM test4 WHERE b = 'Cote' COLLATE case_insensitive;
613
614-- foreign keys (should use collation of primary key)
615
616-- PK is case-sensitive, FK is case-insensitive
617CREATE TABLE test10pk (x text COLLATE case_sensitive PRIMARY KEY);
618INSERT INTO test10pk VALUES ('abc'), ('def'), ('ghi');
619CREATE TABLE test10fk (x text COLLATE case_insensitive REFERENCES test10pk (x) ON UPDATE CASCADE ON DELETE CASCADE);
620INSERT INTO test10fk VALUES ('abc');  -- ok
621INSERT INTO test10fk VALUES ('ABC');  -- error
622INSERT INTO test10fk VALUES ('xyz');  -- error
623SELECT * FROM test10pk;
624SELECT * FROM test10fk;
625-- restrict update even though the values are "equal" in the FK table
626UPDATE test10fk SET x = 'ABC' WHERE x = 'abc';  -- error
627SELECT * FROM test10fk;
628DELETE FROM test10pk WHERE x = 'abc';
629SELECT * FROM test10pk;
630SELECT * FROM test10fk;
631
632-- PK is case-insensitive, FK is case-sensitive
633CREATE TABLE test11pk (x text COLLATE case_insensitive PRIMARY KEY);
634INSERT INTO test11pk VALUES ('abc'), ('def'), ('ghi');
635CREATE TABLE test11fk (x text COLLATE case_sensitive REFERENCES test11pk (x) ON UPDATE CASCADE ON DELETE CASCADE);
636INSERT INTO test11fk VALUES ('abc');  -- ok
637INSERT INTO test11fk VALUES ('ABC');  -- ok
638INSERT INTO test11fk VALUES ('xyz');  -- error
639SELECT * FROM test11pk;
640SELECT * FROM test11fk;
641-- cascade update even though the values are "equal" in the PK table
642UPDATE test11pk SET x = 'ABC' WHERE x = 'abc';
643SELECT * FROM test11fk;
644DELETE FROM test11pk WHERE x = 'abc';
645SELECT * FROM test11pk;
646SELECT * FROM test11fk;
647
648-- partitioning
649CREATE TABLE test20 (a int, b text COLLATE case_insensitive) PARTITION BY LIST (b);
650CREATE TABLE test20_1 PARTITION OF test20 FOR VALUES IN ('abc');
651INSERT INTO test20 VALUES (1, 'abc');
652INSERT INTO test20 VALUES (2, 'ABC');
653SELECT * FROM test20_1;
654
655CREATE TABLE test21 (a int, b text COLLATE case_insensitive) PARTITION BY RANGE (b);
656CREATE TABLE test21_1 PARTITION OF test21 FOR VALUES FROM ('ABC') TO ('DEF');
657INSERT INTO test21 VALUES (1, 'abc');
658INSERT INTO test21 VALUES (2, 'ABC');
659SELECT * FROM test21_1;
660
661CREATE TABLE test22 (a int, b text COLLATE case_sensitive) PARTITION BY HASH (b);
662CREATE TABLE test22_0 PARTITION OF test22 FOR VALUES WITH (MODULUS 2, REMAINDER 0);
663CREATE TABLE test22_1 PARTITION OF test22 FOR VALUES WITH (MODULUS 2, REMAINDER 1);
664INSERT INTO test22 VALUES (1, 'def');
665INSERT INTO test22 VALUES (2, 'DEF');
666-- they end up in different partitions
667SELECT (SELECT count(*) FROM test22_0) = (SELECT count(*) FROM test22_1);
668
669CREATE TABLE test23 (a int, b text COLLATE case_insensitive) PARTITION BY HASH (b);
670CREATE TABLE test23_0 PARTITION OF test23 FOR VALUES WITH (MODULUS 2, REMAINDER 0);
671CREATE TABLE test23_1 PARTITION OF test23 FOR VALUES WITH (MODULUS 2, REMAINDER 1);
672INSERT INTO test23 VALUES (1, 'def');
673INSERT INTO test23 VALUES (2, 'DEF');
674-- they end up in the same partition (but it's platform-dependent which one)
675SELECT (SELECT count(*) FROM test23_0) <> (SELECT count(*) FROM test23_1);
676
677CREATE TABLE test30 (a int, b char(3) COLLATE case_insensitive) PARTITION BY LIST (b);
678CREATE TABLE test30_1 PARTITION OF test30 FOR VALUES IN ('abc');
679INSERT INTO test30 VALUES (1, 'abc');
680INSERT INTO test30 VALUES (2, 'ABC');
681SELECT * FROM test30_1;
682
683CREATE TABLE test31 (a int, b char(3) COLLATE case_insensitive) PARTITION BY RANGE (b);
684CREATE TABLE test31_1 PARTITION OF test31 FOR VALUES FROM ('ABC') TO ('DEF');
685INSERT INTO test31 VALUES (1, 'abc');
686INSERT INTO test31 VALUES (2, 'ABC');
687SELECT * FROM test31_1;
688
689CREATE TABLE test32 (a int, b char(3) COLLATE case_sensitive) PARTITION BY HASH (b);
690CREATE TABLE test32_0 PARTITION OF test32 FOR VALUES WITH (MODULUS 2, REMAINDER 0);
691CREATE TABLE test32_1 PARTITION OF test32 FOR VALUES WITH (MODULUS 2, REMAINDER 1);
692INSERT INTO test32 VALUES (1, 'def');
693INSERT INTO test32 VALUES (2, 'DEF');
694-- they end up in different partitions
695SELECT (SELECT count(*) FROM test32_0) = (SELECT count(*) FROM test32_1);
696
697CREATE TABLE test33 (a int, b char(3) COLLATE case_insensitive) PARTITION BY HASH (b);
698CREATE TABLE test33_0 PARTITION OF test33 FOR VALUES WITH (MODULUS 2, REMAINDER 0);
699CREATE TABLE test33_1 PARTITION OF test33 FOR VALUES WITH (MODULUS 2, REMAINDER 1);
700INSERT INTO test33 VALUES (1, 'def');
701INSERT INTO test33 VALUES (2, 'DEF');
702-- they end up in the same partition (but it's platform-dependent which one)
703SELECT (SELECT count(*) FROM test33_0) <> (SELECT count(*) FROM test33_1);
704
705
706-- cleanup
707SET client_min_messages TO warning;
708DROP SCHEMA collate_tests CASCADE;
709RESET search_path;
710
711-- leave a collation for pg_upgrade test
712CREATE COLLATION coll_icu_upgrade FROM "und-x-icu";
713