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
336set enable_seqscan = off;
337explain (costs off)
338select * from collate_test1 where b ilike 'abc';
339select * from collate_test1 where b ilike 'abc';
340explain (costs off)
341select * from collate_test1 where b ilike 'ABC';
342select * from collate_test1 where b ilike 'ABC';
343reset enable_seqscan;
344
345
346-- schema manipulation commands
347
348CREATE ROLE regress_test_role;
349CREATE SCHEMA test_schema;
350
351-- We need to do this this way to cope with varying names for encodings:
352do $$
353BEGIN
354  EXECUTE 'CREATE COLLATION test0 (provider = icu, locale = ' ||
355          quote_literal(current_setting('lc_collate')) || ');';
356END
357$$;
358CREATE COLLATION test0 FROM "C"; -- fail, duplicate name
359do $$
360BEGIN
361  EXECUTE 'CREATE COLLATION test1 (provider = icu, lc_collate = ' ||
362          quote_literal(current_setting('lc_collate')) ||
363          ', lc_ctype = ' ||
364          quote_literal(current_setting('lc_ctype')) || ');';
365END
366$$;
367CREATE COLLATION test3 (provider = icu, lc_collate = 'en_US.utf8'); -- fail, need lc_ctype
368CREATE COLLATION testx (provider = icu, locale = 'nonsense'); /* never fails with ICU */  DROP COLLATION testx;
369
370CREATE COLLATION test4 FROM nonsense;
371CREATE COLLATION test5 FROM test0;
372
373SELECT collname FROM pg_collation WHERE collname LIKE 'test%' ORDER BY 1;
374
375ALTER COLLATION test1 RENAME TO test11;
376ALTER COLLATION test0 RENAME TO test11; -- fail
377ALTER COLLATION test1 RENAME TO test22; -- fail
378
379ALTER COLLATION test11 OWNER TO regress_test_role;
380ALTER COLLATION test11 OWNER TO nonsense;
381ALTER COLLATION test11 SET SCHEMA test_schema;
382
383COMMENT ON COLLATION test0 IS 'US English';
384
385SELECT collname, nspname, obj_description(pg_collation.oid, 'pg_collation')
386    FROM pg_collation JOIN pg_namespace ON (collnamespace = pg_namespace.oid)
387    WHERE collname LIKE 'test%'
388    ORDER BY 1;
389
390DROP COLLATION test0, test_schema.test11, test5;
391DROP COLLATION test0; -- fail
392DROP COLLATION IF EXISTS test0;
393
394SELECT collname FROM pg_collation WHERE collname LIKE 'test%';
395
396DROP SCHEMA test_schema;
397DROP ROLE regress_test_role;
398
399
400-- ALTER
401
402ALTER COLLATION "en-x-icu" REFRESH VERSION;
403
404
405-- dependencies
406
407CREATE COLLATION test0 FROM "C";
408
409CREATE TABLE collate_dep_test1 (a int, b text COLLATE test0);
410CREATE DOMAIN collate_dep_dom1 AS text COLLATE test0;
411CREATE TYPE collate_dep_test2 AS (x int, y text COLLATE test0);
412CREATE VIEW collate_dep_test3 AS SELECT text 'foo' COLLATE test0 AS foo;
413CREATE TABLE collate_dep_test4t (a int, b text);
414CREATE INDEX collate_dep_test4i ON collate_dep_test4t (b COLLATE test0);
415
416DROP COLLATION test0 RESTRICT; -- fail
417DROP COLLATION test0 CASCADE;
418
419\d collate_dep_test1
420\d collate_dep_test2
421
422DROP TABLE collate_dep_test1, collate_dep_test4t;
423DROP TYPE collate_dep_test2;
424
425-- test range types and collations
426
427create type textrange_c as range(subtype=text, collation="C");
428create type textrange_en_us as range(subtype=text, collation="en-x-icu");
429
430select textrange_c('A','Z') @> 'b'::text;
431select textrange_en_us('A','Z') @> 'b'::text;
432
433drop type textrange_c;
434drop type textrange_en_us;
435
436
437-- cleanup
438DROP SCHEMA collate_tests CASCADE;
439RESET search_path;
440
441-- leave a collation for pg_upgrade test
442CREATE COLLATION coll_icu_upgrade FROM "und-x-icu";
443