3 -- Test various data entry syntaxes.
6 -- SQL92 string continuation syntax
7 -- E021-03 character string literals
11 AS "Three lines to one";
13 -- illegal string continuation syntax
15 ' - next line' /* this comment is not allowed here */
17 AS "Illegal comment within continuation";
20 SET standard_conforming_strings TO on;
22 SELECT U&'d\0061t\+000061' AS U&"d\0061t\+000061";
23 SELECT U&'d!0061t\+000061' UESCAPE '!' AS U&"d*0061t\+000061" UESCAPE '*';
25 SELECT U&' \' UESCAPE '!' AS "tricky";
26 SELECT 'tricky' AS U&"\" UESCAPE '!';
28 SELECT U&'wrong: \061';
29 SELECT U&'wrong: \+0061';
30 SELECT U&'wrong: +0061' UESCAPE '+';
32 SET standard_conforming_strings TO off;
34 SELECT U&'d\0061t\+000061' AS U&"d\0061t\+000061";
35 SELECT U&'d!0061t\+000061' UESCAPE '!' AS U&"d*0061t\+000061" UESCAPE '*';
37 SELECT U&' \' UESCAPE '!' AS "tricky";
38 SELECT 'tricky' AS U&"\" UESCAPE '!';
40 SELECT U&'wrong: \061';
41 SELECT U&'wrong: \+0061';
42 SELECT U&'wrong: +0061' UESCAPE '+';
44 RESET standard_conforming_strings;
47 -- test conversions between various string types
48 -- E021-10 implicit casting among the character data types
51 SELECT CAST(f1 AS text) AS "text(char)" FROM CHAR_TBL;
53 SELECT CAST(f1 AS text) AS "text(varchar)" FROM VARCHAR_TBL;
55 SELECT CAST(name 'namefield' AS text) AS "text(name)";
57 -- since this is an explicit cast, it should truncate w/o error:
58 SELECT CAST(f1 AS char(10)) AS "char(text)" FROM TEXT_TBL;
59 -- note: implicit-cast case is tested in char.sql
61 SELECT CAST(f1 AS char(20)) AS "char(text)" FROM TEXT_TBL;
63 SELECT CAST(f1 AS char(10)) AS "char(varchar)" FROM VARCHAR_TBL;
65 SELECT CAST(name 'namefield' AS char(10)) AS "char(name)";
67 SELECT CAST(f1 AS varchar) AS "varchar(text)" FROM TEXT_TBL;
69 SELECT CAST(f1 AS varchar) AS "varchar(char)" FROM CHAR_TBL;
71 SELECT CAST(name 'namefield' AS varchar) AS "varchar(name)";
74 -- test SQL92 string functions
75 -- E### and T### are feature reference numbers from SQL99
78 -- E021-09 trim function
79 SELECT TRIM(BOTH FROM ' bunch o blanks ') = 'bunch o blanks' AS "bunch o blanks";
81 SELECT TRIM(LEADING FROM ' bunch o blanks ') = 'bunch o blanks ' AS "bunch o blanks ";
83 SELECT TRIM(TRAILING FROM ' bunch o blanks ') = ' bunch o blanks' AS " bunch o blanks";
85 SELECT TRIM(BOTH 'x' FROM 'xxxxxsome Xsxxxxx') = 'some Xs' AS "some Xs";
87 -- E021-06 substring expression
88 SELECT SUBSTRING('1234567890' FROM 3) = '34567890' AS "34567890";
90 SELECT SUBSTRING('1234567890' FROM 4 FOR 3) = '456' AS "456";
92 -- T581 regular expression substring (with SQL99's bizarre regexp syntax)
93 SELECT SUBSTRING('abcdefg' FROM 'a#"(b_d)#"%' FOR '#') AS "bcd";
95 -- No match should return NULL
96 SELECT SUBSTRING('abcdefg' FROM '#"(b_d)#"%' FOR '#') IS NULL AS "True";
98 -- Null inputs should return NULL
99 SELECT SUBSTRING('abcdefg' FROM '(b|c)' FOR NULL) IS NULL AS "True";
100 SELECT SUBSTRING(NULL FROM '(b|c)' FOR '#') IS NULL AS "True";
101 SELECT SUBSTRING('abcdefg' FROM NULL FOR '#') IS NULL AS "True";
103 -- PostgreSQL extension to allow omitting the escape character;
104 -- here the regexp is taken as Posix syntax
105 SELECT SUBSTRING('abcdefg' FROM 'c.e') AS "cde";
107 -- With a parenthesized subexpression, return only what matches the subexpr
108 SELECT SUBSTRING('abcdefg' FROM 'b(.*)f') AS "cde";
110 -- PostgreSQL extension to allow using back reference in replace string;
111 SELECT regexp_replace('1112223333', E'(\\d{3})(\\d{3})(\\d{4})', E'(\\1) \\2-\\3');
112 SELECT regexp_replace('AAA BBB CCC ', E'\\s+', ' ', 'g');
113 SELECT regexp_replace('AAA', '^|$', 'Z', 'g');
114 SELECT regexp_replace('AAA aaa', 'A+', 'Z', 'gi');
115 -- invalid regexp option
116 SELECT regexp_replace('AAA aaa', 'A+', 'Z', 'z');
118 -- set so we can tell NULL from empty string
121 -- return all matches from regexp
122 SELECT regexp_matches('foobarbequebaz', $re$(bar)(beque)$re$);
124 -- test case insensitive
125 SELECT regexp_matches('foObARbEqUEbAz', $re$(bar)(beque)$re$, 'i');
127 -- global option - more than one match
128 SELECT regexp_matches('foobarbequebazilbarfbonk', $re$(b[^b]+)(b[^b]+)$re$, 'g');
130 -- empty capture group (matched empty string)
131 SELECT regexp_matches('foobarbequebaz', $re$(bar)(.*)(beque)$re$);
133 SELECT regexp_matches('foobarbequebaz', $re$(bar)(.+)(beque)$re$);
134 -- optional capture group did not match, null entry in array
135 SELECT regexp_matches('foobarbequebaz', $re$(bar)(.+)?(beque)$re$);
138 SELECT regexp_matches('foobarbequebaz', $re$barbeque$re$);
141 SELECT regexp_matches('foobarbequebaz', $re$(bar)(beque)$re$, 'gz');
142 SELECT regexp_matches('foobarbequebaz', $re$(barbeque$re$);
143 SELECT regexp_matches('foobarbequebaz', $re$(bar)(beque){2,1}$re$);
145 -- split string on regexp
146 SELECT foo, length(foo) FROM regexp_split_to_table('the quick brown fox jumped over the lazy dog', $re$\s+$re$) AS foo;
147 SELECT regexp_split_to_array('the quick brown fox jumped over the lazy dog', $re$\s+$re$);
149 SELECT foo, length(foo) FROM regexp_split_to_table('the quick brown fox jumped over the lazy dog', $re$\s*$re$) AS foo;
150 SELECT regexp_split_to_array('the quick brown fox jumped over the lazy dog', $re$\s*$re$);
151 SELECT foo, length(foo) FROM regexp_split_to_table('the quick brown fox jumped over the lazy dog', '') AS foo;
152 SELECT regexp_split_to_array('the quick brown fox jumped over the lazy dog', '');
154 SELECT foo, length(foo) FROM regexp_split_to_table('thE QUick bROWn FOx jUMPed ovEr THE lazy dOG', 'e', 'i') AS foo;
155 SELECT regexp_split_to_array('thE QUick bROWn FOx jUMPed ovEr THE lazy dOG', 'e', 'i');
156 -- no match of pattern
157 SELECT foo, length(foo) FROM regexp_split_to_table('the quick brown fox jumped over the lazy dog', 'nomatch') AS foo;
158 SELECT regexp_split_to_array('the quick brown fox jumped over the lazy dog', 'nomatch');
160 SELECT regexp_split_to_array('123456','1');
161 SELECT regexp_split_to_array('123456','6');
162 SELECT regexp_split_to_array('123456','.');
164 SELECT foo, length(foo) FROM regexp_split_to_table('thE QUick bROWn FOx jUMPed ovEr THE lazy dOG', 'e', 'zippy') AS foo;
165 SELECT regexp_split_to_array('thE QUick bROWn FOx jUMPed ovEr THE lazy dOG', 'e', 'iz');
166 -- global option meaningless for regexp_split
167 SELECT foo, length(foo) FROM regexp_split_to_table('thE QUick bROWn FOx jUMPed ovEr THE lazy dOG', 'e', 'g') AS foo;
168 SELECT regexp_split_to_array('thE QUick bROWn FOx jUMPed ovEr THE lazy dOG', 'e', 'g');
170 -- change NULL-display back
173 -- E021-11 position expression
174 SELECT POSITION('4' IN '1234567890') = '4' AS "4";
176 SELECT POSITION('5' IN '1234567890') = '5' AS "5";
178 -- T312 character overlay function
179 SELECT OVERLAY('abcdef' PLACING '45' FROM 4) AS "abc45f";
181 SELECT OVERLAY('yabadoo' PLACING 'daba' FROM 5) AS "yabadaba";
183 SELECT OVERLAY('yabadoo' PLACING 'daba' FROM 5 FOR 0) AS "yabadabadoo";
185 SELECT OVERLAY('babosa' PLACING 'ubb' FROM 2 FOR 4) AS "bubba";
189 -- Be sure to form every test as a LIKE/NOT LIKE pair.
193 -- E061-04 like predicate
194 SELECT 'hawkeye' LIKE 'h%' AS "true";
195 SELECT 'hawkeye' NOT LIKE 'h%' AS "false";
197 SELECT 'hawkeye' LIKE 'H%' AS "false";
198 SELECT 'hawkeye' NOT LIKE 'H%' AS "true";
200 SELECT 'hawkeye' LIKE 'indio%' AS "false";
201 SELECT 'hawkeye' NOT LIKE 'indio%' AS "true";
203 SELECT 'hawkeye' LIKE 'h%eye' AS "true";
204 SELECT 'hawkeye' NOT LIKE 'h%eye' AS "false";
206 SELECT 'indio' LIKE '_ndio' AS "true";
207 SELECT 'indio' NOT LIKE '_ndio' AS "false";
209 SELECT 'indio' LIKE 'in__o' AS "true";
210 SELECT 'indio' NOT LIKE 'in__o' AS "false";
212 SELECT 'indio' LIKE 'in_o' AS "false";
213 SELECT 'indio' NOT LIKE 'in_o' AS "true";
215 -- unused escape character
216 SELECT 'hawkeye' LIKE 'h%' ESCAPE '#' AS "true";
217 SELECT 'hawkeye' NOT LIKE 'h%' ESCAPE '#' AS "false";
219 SELECT 'indio' LIKE 'ind_o' ESCAPE '$' AS "true";
220 SELECT 'indio' NOT LIKE 'ind_o' ESCAPE '$' AS "false";
223 -- E061-05 like predicate with escape clause
224 SELECT 'h%' LIKE 'h#%' ESCAPE '#' AS "true";
225 SELECT 'h%' NOT LIKE 'h#%' ESCAPE '#' AS "false";
227 SELECT 'h%wkeye' LIKE 'h#%' ESCAPE '#' AS "false";
228 SELECT 'h%wkeye' NOT LIKE 'h#%' ESCAPE '#' AS "true";
230 SELECT 'h%wkeye' LIKE 'h#%%' ESCAPE '#' AS "true";
231 SELECT 'h%wkeye' NOT LIKE 'h#%%' ESCAPE '#' AS "false";
233 SELECT 'h%awkeye' LIKE 'h#%a%k%e' ESCAPE '#' AS "true";
234 SELECT 'h%awkeye' NOT LIKE 'h#%a%k%e' ESCAPE '#' AS "false";
236 SELECT 'indio' LIKE '_ndio' ESCAPE '$' AS "true";
237 SELECT 'indio' NOT LIKE '_ndio' ESCAPE '$' AS "false";
239 SELECT 'i_dio' LIKE 'i$_d_o' ESCAPE '$' AS "true";
240 SELECT 'i_dio' NOT LIKE 'i$_d_o' ESCAPE '$' AS "false";
242 SELECT 'i_dio' LIKE 'i$_nd_o' ESCAPE '$' AS "false";
243 SELECT 'i_dio' NOT LIKE 'i$_nd_o' ESCAPE '$' AS "true";
245 SELECT 'i_dio' LIKE 'i$_d%o' ESCAPE '$' AS "true";
246 SELECT 'i_dio' NOT LIKE 'i$_d%o' ESCAPE '$' AS "false";
248 -- escape character same as pattern character
249 SELECT 'maca' LIKE 'm%aca' ESCAPE '%' AS "true";
250 SELECT 'maca' NOT LIKE 'm%aca' ESCAPE '%' AS "false";
252 SELECT 'ma%a' LIKE 'm%a%%a' ESCAPE '%' AS "true";
253 SELECT 'ma%a' NOT LIKE 'm%a%%a' ESCAPE '%' AS "false";
255 SELECT 'bear' LIKE 'b_ear' ESCAPE '_' AS "true";
256 SELECT 'bear' NOT LIKE 'b_ear' ESCAPE '_' AS "false";
258 SELECT 'be_r' LIKE 'b_e__r' ESCAPE '_' AS "true";
259 SELECT 'be_r' NOT LIKE 'b_e__r' ESCAPE '_' AS "false";
261 SELECT 'be_r' LIKE '__e__r' ESCAPE '_' AS "false";
262 SELECT 'be_r' NOT LIKE '__e__r' ESCAPE '_' AS "true";
266 -- test ILIKE (case-insensitive LIKE)
267 -- Be sure to form every test as an ILIKE/NOT ILIKE pair.
270 SELECT 'hawkeye' ILIKE 'h%' AS "true";
271 SELECT 'hawkeye' NOT ILIKE 'h%' AS "false";
273 SELECT 'hawkeye' ILIKE 'H%' AS "true";
274 SELECT 'hawkeye' NOT ILIKE 'H%' AS "false";
276 SELECT 'hawkeye' ILIKE 'H%Eye' AS "true";
277 SELECT 'hawkeye' NOT ILIKE 'H%Eye' AS "false";
279 SELECT 'Hawkeye' ILIKE 'h%' AS "true";
280 SELECT 'Hawkeye' NOT ILIKE 'h%' AS "false";
283 -- test %/_ combination cases, cf bug #4821
286 SELECT 'foo' LIKE '_%' as t, 'f' LIKE '_%' as t, '' LIKE '_%' as f;
287 SELECT 'foo' LIKE '%_' as t, 'f' LIKE '%_' as t, '' LIKE '%_' as f;
289 SELECT 'foo' LIKE '__%' as t, 'foo' LIKE '___%' as t, 'foo' LIKE '____%' as f;
290 SELECT 'foo' LIKE '%__' as t, 'foo' LIKE '%___' as t, 'foo' LIKE '%____' as f;
294 -- test implicit type conversion
297 -- E021-07 character concatenation
298 SELECT 'unknown' || ' and unknown' AS "Concat unknown types";
300 SELECT text 'text' || ' and unknown' AS "Concat text to unknown type";
302 SELECT char(20) 'characters' || ' and text' AS "Concat char to unknown type";
304 SELECT text 'text' || char(20) ' and characters' AS "Concat text to char";
306 SELECT text 'text' || varchar ' and varchar' AS "Concat text to varchar";
309 -- test substr with toasted text values
311 CREATE TABLE toasttest(f1 text);
313 insert into toasttest values(repeat('1234567890',10000));
314 insert into toasttest values(repeat('1234567890',10000));
317 -- Ensure that some values are uncompressed, to test the faster substring
318 -- operation used in that case
320 alter table toasttest alter column f1 set storage external;
321 insert into toasttest values(repeat('1234567890',10000));
322 insert into toasttest values(repeat('1234567890',10000));
324 -- If the starting position is zero or less, then return from the start of the string
325 -- adjusting the length to be consistent with the "negative start" per SQL92.
326 SELECT substr(f1, -1, 5) from toasttest;
328 -- If the length is less than zero, an ERROR is thrown.
329 SELECT substr(f1, 5, -1) from toasttest;
331 -- If no third argument (length) is provided, the length to the end of the
332 -- string is assumed.
333 SELECT substr(f1, 99995) from toasttest;
335 -- If start plus length is > string length, the result is truncated to
337 SELECT substr(f1, 99995, 10) from toasttest;
339 DROP TABLE toasttest;
342 -- test substr with toasted bytea values
344 CREATE TABLE toasttest(f1 bytea);
346 insert into toasttest values(decode(repeat('1234567890',10000),'escape'));
347 insert into toasttest values(decode(repeat('1234567890',10000),'escape'));
350 -- Ensure that some values are uncompressed, to test the faster substring
351 -- operation used in that case
353 alter table toasttest alter column f1 set storage external;
354 insert into toasttest values(decode(repeat('1234567890',10000),'escape'));
355 insert into toasttest values(decode(repeat('1234567890',10000),'escape'));
357 -- If the starting position is zero or less, then return from the start of the string
358 -- adjusting the length to be consistent with the "negative start" per SQL92.
359 SELECT substr(f1, -1, 5) from toasttest;
361 -- If the length is less than zero, an ERROR is thrown.
362 SELECT substr(f1, 5, -1) from toasttest;
364 -- If no third argument (length) is provided, the length to the end of the
365 -- string is assumed.
366 SELECT substr(f1, 99995) from toasttest;
368 -- If start plus length is > string length, the result is truncated to
370 SELECT substr(f1, 99995, 10) from toasttest;
372 DROP TABLE toasttest;
374 -- test internally compressing datums
376 -- this tests compressing a datum to a very small size which exercises a
377 -- corner case in packed-varlena handling: even though small, the compressed
378 -- datum must be given a 4-byte header because there are no bits to indicate
379 -- compression in a 1-byte header
381 CREATE TABLE toasttest (c char(4096));
382 INSERT INTO toasttest VALUES('x');
383 SELECT length(c), c::text FROM toasttest;
384 SELECT c FROM toasttest;
385 DROP TABLE toasttest;
391 SELECT length('abcdef') AS "length_6";
397 SELECT strpos('abcdef', 'cd') AS "pos_3";
399 SELECT strpos('abcdef', 'xy') AS "pos_0";
404 SELECT replace('abcdef', 'de', '45') AS "abc45f";
406 SELECT replace('yabadabadoo', 'ba', '123') AS "ya123da123doo";
408 SELECT replace('yabadoo', 'bad', '') AS "yaoo";
413 select split_part('joeuser@mydatabase','@',0) AS "an error";
415 select split_part('joeuser@mydatabase','@',1) AS "joeuser";
417 select split_part('joeuser@mydatabase','@',2) AS "mydatabase";
419 select split_part('joeuser@mydatabase','@',3) AS "empty string";
421 select split_part('@joeuser@mydatabase@','@',2) AS "joeuser";
426 select to_hex(256*256*256 - 1) AS "ffffff";
428 select to_hex(256::bigint*256::bigint*256::bigint*256::bigint - 1) AS "ffffffff";
431 -- MD5 test suite - from IETF RFC 1321
432 -- (see: ftp://ftp.rfc-editor.org/in-notes/rfc1321.txt)
434 select md5('') = 'd41d8cd98f00b204e9800998ecf8427e' AS "TRUE";
436 select md5('a') = '0cc175b9c0f1b6a831c399e269772661' AS "TRUE";
438 select md5('abc') = '900150983cd24fb0d6963f7d28e17f72' AS "TRUE";
440 select md5('message digest') = 'f96b697d7cb7938d525a2f31aaf161d0' AS "TRUE";
442 select md5('abcdefghijklmnopqrstuvwxyz') = 'c3fcd3d76192e4007dfb496cca67e13b' AS "TRUE";
444 select md5('ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz0123456789') = 'd174ab98d277d9f5a5611c2c9f419d9f' AS "TRUE";
446 select md5('12345678901234567890123456789012345678901234567890123456789012345678901234567890') = '57edf4a22be3c955ac49da2e2107b67a' AS "TRUE";
448 select md5(''::bytea) = 'd41d8cd98f00b204e9800998ecf8427e' AS "TRUE";
450 select md5('a'::bytea) = '0cc175b9c0f1b6a831c399e269772661' AS "TRUE";
452 select md5('abc'::bytea) = '900150983cd24fb0d6963f7d28e17f72' AS "TRUE";
454 select md5('message digest'::bytea) = 'f96b697d7cb7938d525a2f31aaf161d0' AS "TRUE";
456 select md5('abcdefghijklmnopqrstuvwxyz'::bytea) = 'c3fcd3d76192e4007dfb496cca67e13b' AS "TRUE";
458 select md5('ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz0123456789'::bytea) = 'd174ab98d277d9f5a5611c2c9f419d9f' AS "TRUE";
460 select md5('12345678901234567890123456789012345678901234567890123456789012345678901234567890'::bytea) = '57edf4a22be3c955ac49da2e2107b67a' AS "TRUE";
463 -- test behavior of escape_string_warning and standard_conforming_strings options
465 set escape_string_warning = off;
466 set standard_conforming_strings = off;
468 show escape_string_warning;
469 show standard_conforming_strings;
471 set escape_string_warning = on;
472 set standard_conforming_strings = on;
474 show escape_string_warning;
475 show standard_conforming_strings;
477 select 'a\bcd' as f1, 'a\b''cd' as f2, 'a\b''''cd' as f3, 'abcd\' as f4, 'ab\''cd' as f5, '\\' as f6;
479 set standard_conforming_strings = off;
481 select 'a\\bcd' as f1, 'a\\b\'cd' as f2, 'a\\b\'''cd' as f3, 'abcd\\' as f4, 'ab\\\'cd' as f5, '\\\\' as f6;
483 set escape_string_warning = off;
484 set standard_conforming_strings = on;
486 select 'a\bcd' as f1, 'a\b''cd' as f2, 'a\b''''cd' as f3, 'abcd\' as f4, 'ab\''cd' as f5, '\\' as f6;
488 set standard_conforming_strings = off;
490 select 'a\\bcd' as f1, 'a\\b\'cd' as f2, 'a\\b\'''cd' as f3, 'abcd\\' as f4, 'ab\\\'cd' as f5, '\\\\' as f6;
494 -- Additional string functions
497 SELECT initcap('hi THOMAS');
499 SELECT lpad('hi', 5, 'xy');
500 SELECT lpad('hi', 5);
501 SELECT lpad('hi', -5, 'xy');
502 SELECT lpad('hello', 2);
503 SELECT lpad('hi', 5, '');
505 SELECT rpad('hi', 5, 'xy');
506 SELECT rpad('hi', 5);
507 SELECT rpad('hi', -5, 'xy');
508 SELECT rpad('hello', 2);
509 SELECT rpad('hi', 5, '');
511 SELECT ltrim('zzzytrim', 'xyz');
513 SELECT translate('', '14', 'ax');
514 SELECT translate('12345', '14', 'ax');
522 SELECT repeat('Pg', 4);
523 SELECT repeat('Pg', -4);
525 SELECT trim(E'\\000'::bytea from E'\\000Tom\\000'::bytea);
526 SELECT btrim(E'\\000trim\\000'::bytea, E'\\000'::bytea);
527 SELECT btrim(''::bytea, E'\\000'::bytea);
528 SELECT btrim(E'\\000trim\\000'::bytea, ''::bytea);