summaryrefslogtreecommitdiffstats
path: root/src/test/regress/sql/rangetypes.sql
blob: 1a10f67f1992f308b300fb8fd2acc1dee0e67daf (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
-- Tests for range data types.

--
-- test input parser
-- (type textrange was already made in test_setup.sql)
--

-- negative tests; should fail
select ''::textrange;
select '-[a,z)'::textrange;
select '[a,z) - '::textrange;
select '(",a)'::textrange;
select '(,,a)'::textrange;
select '(),a)'::textrange;
select '(a,))'::textrange;
select '(],a)'::textrange;
select '(a,])'::textrange;
select '[z,a]'::textrange;

-- should succeed
select '  empty  '::textrange;
select ' ( empty, empty )  '::textrange;
select ' ( " a " " a ", " z " " z " )  '::textrange;
select '(a,)'::textrange;
select '[,z]'::textrange;
select '[a,]'::textrange;
select '(,)'::textrange;
select '[ , ]'::textrange;
select '["",""]'::textrange;
select '[",",","]'::textrange;
select '["\\","\\"]'::textrange;
select '(\\,a)'::textrange;
select '((,z)'::textrange;
select '([,z)'::textrange;
select '(!,()'::textrange;
select '(!,[)'::textrange;
select '[a,a]'::textrange;
-- these are allowed but normalize to empty:
select '[a,a)'::textrange;
select '(a,a]'::textrange;
select '(a,a)'::textrange;

--
-- create some test data and test the operators
--

CREATE TABLE numrange_test (nr NUMRANGE);
create index numrange_test_btree on numrange_test(nr);

INSERT INTO numrange_test VALUES('[,)');
INSERT INTO numrange_test VALUES('[3,]');
INSERT INTO numrange_test VALUES('[, 5)');
INSERT INTO numrange_test VALUES(numrange(1.1, 2.2));
INSERT INTO numrange_test VALUES('empty');
INSERT INTO numrange_test VALUES(numrange(1.7, 1.7, '[]'));

SELECT nr, isempty(nr), lower(nr), upper(nr) FROM numrange_test;
SELECT nr, lower_inc(nr), lower_inf(nr), upper_inc(nr), upper_inf(nr) FROM numrange_test;

SELECT * FROM numrange_test WHERE range_contains(nr, numrange(1.9,1.91));
SELECT * FROM numrange_test WHERE nr @> numrange(1.0,10000.1);
SELECT * FROM numrange_test WHERE range_contained_by(numrange(-1e7,-10000.1), nr);
SELECT * FROM numrange_test WHERE 1.9 <@ nr;

select * from numrange_test where nr = 'empty';
select * from numrange_test where nr = '(1.1, 2.2)';
select * from numrange_test where nr = '[1.1, 2.2)';
select * from numrange_test where nr < 'empty';
select * from numrange_test where nr < numrange(-1000.0, -1000.0,'[]');
select * from numrange_test where nr < numrange(0.0, 1.0,'[]');
select * from numrange_test where nr < numrange(1000.0, 1001.0,'[]');
select * from numrange_test where nr <= 'empty';
select * from numrange_test where nr >= 'empty';
select * from numrange_test where nr > 'empty';
select * from numrange_test where nr > numrange(-1001.0, -1000.0,'[]');
select * from numrange_test where nr > numrange(0.0, 1.0,'[]');
select * from numrange_test where nr > numrange(1000.0, 1000.0,'[]');

select numrange(2.0, 1.0);

select numrange(2.0, 3.0) -|- numrange(3.0, 4.0);
select range_adjacent(numrange(2.0, 3.0), numrange(3.1, 4.0));
select range_adjacent(numrange(2.0, 3.0), numrange(3.1, null));
select numrange(2.0, 3.0, '[]') -|- numrange(3.0, 4.0, '()');
select numrange(1.0, 2.0) -|- numrange(2.0, 3.0,'[]');
select range_adjacent(numrange(2.0, 3.0, '(]'), numrange(1.0, 2.0, '(]'));

select numrange(1.1, 3.3) <@ numrange(0.1,10.1);
select numrange(0.1, 10.1) <@ numrange(1.1,3.3);

select numrange(1.1, 2.2) - numrange(2.0, 3.0);
select numrange(1.1, 2.2) - numrange(2.2, 3.0);
select numrange(1.1, 2.2,'[]') - numrange(2.0, 3.0);
select range_minus(numrange(10.1,12.2,'[]'), numrange(110.0,120.2,'(]'));
select range_minus(numrange(10.1,12.2,'[]'), numrange(0.0,120.2,'(]'));

select numrange(4.5, 5.5, '[]') && numrange(5.5, 6.5);
select numrange(1.0, 2.0) << numrange(3.0, 4.0);
select numrange(1.0, 3.0,'[]') << numrange(3.0, 4.0,'[]');
select numrange(1.0, 3.0,'()') << numrange(3.0, 4.0,'()');
select numrange(1.0, 2.0) >> numrange(3.0, 4.0);
select numrange(3.0, 70.0) &< numrange(6.6, 100.0);

select numrange(1.1, 2.2) < numrange(1.0, 200.2);
select numrange(1.1, 2.2) < numrange(1.1, 1.2);

select numrange(1.0, 2.0) + numrange(2.0, 3.0);
select numrange(1.0, 2.0) + numrange(1.5, 3.0);
select numrange(1.0, 2.0) + numrange(2.5, 3.0); -- should fail

select range_merge(numrange(1.0, 2.0), numrange(2.0, 3.0));
select range_merge(numrange(1.0, 2.0), numrange(1.5, 3.0));
select range_merge(numrange(1.0, 2.0), numrange(2.5, 3.0)); -- shouldn't fail

select numrange(1.0, 2.0) * numrange(2.0, 3.0);
select numrange(1.0, 2.0) * numrange(1.5, 3.0);
select numrange(1.0, 2.0) * numrange(2.5, 3.0);

select range_intersect_agg(nr) from numrange_test;
select range_intersect_agg(nr) from numrange_test where false;
select range_intersect_agg(nr) from numrange_test where nr @> 4.0;

analyze numrange_test;

create table numrange_test2(nr numrange);
create index numrange_test2_hash_idx on numrange_test2 using hash (nr);

INSERT INTO numrange_test2 VALUES('[, 5)');
INSERT INTO numrange_test2 VALUES(numrange(1.1, 2.2));
INSERT INTO numrange_test2 VALUES(numrange(1.1, 2.2));
INSERT INTO numrange_test2 VALUES(numrange(1.1, 2.2,'()'));
INSERT INTO numrange_test2 VALUES('empty');

select * from numrange_test2 where nr = 'empty'::numrange;
select * from numrange_test2 where nr = numrange(1.1, 2.2);
select * from numrange_test2 where nr = numrange(1.1, 2.3);

set enable_nestloop=t;
set enable_hashjoin=f;
set enable_mergejoin=f;
select * from numrange_test natural join numrange_test2 order by nr;
set enable_nestloop=f;
set enable_hashjoin=t;
set enable_mergejoin=f;
select * from numrange_test natural join numrange_test2 order by nr;
set enable_nestloop=f;
set enable_hashjoin=f;
set enable_mergejoin=t;
select * from numrange_test natural join numrange_test2 order by nr;

set enable_nestloop to default;
set enable_hashjoin to default;
set enable_mergejoin to default;

-- keep numrange_test around to help exercise dump/reload
DROP TABLE numrange_test2;

--
-- Apply a subset of the above tests on a collatable type, too
--

CREATE TABLE textrange_test (tr textrange);
create index textrange_test_btree on textrange_test(tr);

INSERT INTO textrange_test VALUES('[,)');
INSERT INTO textrange_test VALUES('["a",]');
INSERT INTO textrange_test VALUES('[,"q")');
INSERT INTO textrange_test VALUES(textrange('b', 'g'));
INSERT INTO textrange_test VALUES('empty');
INSERT INTO textrange_test VALUES(textrange('d', 'd', '[]'));

SELECT tr, isempty(tr), lower(tr), upper(tr) FROM textrange_test;
SELECT tr, lower_inc(tr), lower_inf(tr), upper_inc(tr), upper_inf(tr) FROM textrange_test;

SELECT * FROM textrange_test WHERE range_contains(tr, textrange('f', 'fx'));
SELECT * FROM textrange_test WHERE tr @> textrange('a', 'z');
SELECT * FROM textrange_test WHERE range_contained_by(textrange('0','9'), tr);
SELECT * FROM textrange_test WHERE 'e'::text <@ tr;

select * from textrange_test where tr = 'empty';
select * from textrange_test where tr = '("b","g")';
select * from textrange_test where tr = '["b","g")';
select * from textrange_test where tr < 'empty';


-- test canonical form for int4range
select int4range(1, 10, '[]');
select int4range(1, 10, '[)');
select int4range(1, 10, '(]');
select int4range(1, 10, '()');
select int4range(1, 2, '()');

-- test canonical form for daterange
select daterange('2000-01-10'::date, '2000-01-20'::date, '[]');
select daterange('2000-01-10'::date, '2000-01-20'::date, '[)');
select daterange('2000-01-10'::date, '2000-01-20'::date, '(]');
select daterange('2000-01-10'::date, '2000-01-20'::date, '()');
select daterange('2000-01-10'::date, '2000-01-11'::date, '()');
select daterange('2000-01-10'::date, '2000-01-11'::date, '(]');
select daterange('-infinity'::date, '2000-01-01'::date, '()');
select daterange('-infinity'::date, '2000-01-01'::date, '[)');
select daterange('2000-01-01'::date, 'infinity'::date, '[)');
select daterange('2000-01-01'::date, 'infinity'::date, '[]');

-- test GiST index that's been built incrementally
create table test_range_gist(ir int4range);
create index test_range_gist_idx on test_range_gist using gist (ir);

insert into test_range_gist select int4range(g, g+10) from generate_series(1,2000) g;
insert into test_range_gist select 'empty'::int4range from generate_series(1,500) g;
insert into test_range_gist select int4range(g, g+10000) from generate_series(1,1000) g;
insert into test_range_gist select 'empty'::int4range from generate_series(1,500) g;
insert into test_range_gist select int4range(NULL,g*10,'(]') from generate_series(1,100) g;
insert into test_range_gist select int4range(g*10,NULL,'(]') from generate_series(1,100) g;
insert into test_range_gist select int4range(g, g+10) from generate_series(1,2000) g;

-- test statistics and selectivity estimation as well
--
-- We don't check the accuracy of selectivity estimation, but at least check
-- it doesn't fall.
analyze test_range_gist;

-- first, verify non-indexed results
SET enable_seqscan    = t;
SET enable_indexscan  = f;
SET enable_bitmapscan = f;

select count(*) from test_range_gist where ir @> 'empty'::int4range;
select count(*) from test_range_gist where ir = int4range(10,20);
select count(*) from test_range_gist where ir @> 10;
select count(*) from test_range_gist where ir @> int4range(10,20);
select count(*) from test_range_gist where ir && int4range(10,20);
select count(*) from test_range_gist where ir <@ int4range(10,50);
select count(*) from test_range_gist where ir << int4range(100,500);
select count(*) from test_range_gist where ir >> int4range(100,500);
select count(*) from test_range_gist where ir &< int4range(100,500);
select count(*) from test_range_gist where ir &> int4range(100,500);
select count(*) from test_range_gist where ir -|- int4range(100,500);
select count(*) from test_range_gist where ir @> '{}'::int4multirange;
select count(*) from test_range_gist where ir @> int4multirange(int4range(10,20), int4range(30,40));
select count(*) from test_range_gist where ir && '{(10,20),(30,40),(50,60)}'::int4multirange;
select count(*) from test_range_gist where ir <@ '{(10,30),(40,60),(70,90)}'::int4multirange;
select count(*) from test_range_gist where ir << int4multirange(int4range(100,200), int4range(400,500));
select count(*) from test_range_gist where ir >> int4multirange(int4range(100,200), int4range(400,500));
select count(*) from test_range_gist where ir &< int4multirange(int4range(100,200), int4range(400,500));
select count(*) from test_range_gist where ir &> int4multirange(int4range(100,200), int4range(400,500));
select count(*) from test_range_gist where ir -|- int4multirange(int4range(100,200), int4range(400,500));

-- now check same queries using index
SET enable_seqscan    = f;
SET enable_indexscan  = t;
SET enable_bitmapscan = f;

select count(*) from test_range_gist where ir @> 'empty'::int4range;
select count(*) from test_range_gist where ir = int4range(10,20);
select count(*) from test_range_gist where ir @> 10;
select count(*) from test_range_gist where ir @> int4range(10,20);
select count(*) from test_range_gist where ir && int4range(10,20);
select count(*) from test_range_gist where ir <@ int4range(10,50);
select count(*) from test_range_gist where ir << int4range(100,500);
select count(*) from test_range_gist where ir >> int4range(100,500);
select count(*) from test_range_gist where ir &< int4range(100,500);
select count(*) from test_range_gist where ir &> int4range(100,500);
select count(*) from test_range_gist where ir -|- int4range(100,500);
select count(*) from test_range_gist where ir @> '{}'::int4multirange;
select count(*) from test_range_gist where ir @> int4multirange(int4range(10,20), int4range(30,40));
select count(*) from test_range_gist where ir && '{(10,20),(30,40),(50,60)}'::int4multirange;
select count(*) from test_range_gist where ir <@ '{(10,30),(40,60),(70,90)}'::int4multirange;
select count(*) from test_range_gist where ir << int4multirange(int4range(100,200), int4range(400,500));
select count(*) from test_range_gist where ir >> int4multirange(int4range(100,200), int4range(400,500));
select count(*) from test_range_gist where ir &< int4multirange(int4range(100,200), int4range(400,500));
select count(*) from test_range_gist where ir &> int4multirange(int4range(100,200), int4range(400,500));
select count(*) from test_range_gist where ir -|- int4multirange(int4range(100,200), int4range(400,500));

-- now check same queries using a bulk-loaded index
drop index test_range_gist_idx;
create index test_range_gist_idx on test_range_gist using gist (ir);

select count(*) from test_range_gist where ir @> 'empty'::int4range;
select count(*) from test_range_gist where ir = int4range(10,20);
select count(*) from test_range_gist where ir @> 10;
select count(*) from test_range_gist where ir @> int4range(10,20);
select count(*) from test_range_gist where ir && int4range(10,20);
select count(*) from test_range_gist where ir <@ int4range(10,50);
select count(*) from test_range_gist where ir << int4range(100,500);
select count(*) from test_range_gist where ir >> int4range(100,500);
select count(*) from test_range_gist where ir &< int4range(100,500);
select count(*) from test_range_gist where ir &> int4range(100,500);
select count(*) from test_range_gist where ir -|- int4range(100,500);
select count(*) from test_range_gist where ir @> '{}'::int4multirange;
select count(*) from test_range_gist where ir @> int4multirange(int4range(10,20), int4range(30,40));
select count(*) from test_range_gist where ir && '{(10,20),(30,40),(50,60)}'::int4multirange;
select count(*) from test_range_gist where ir <@ '{(10,30),(40,60),(70,90)}'::int4multirange;
select count(*) from test_range_gist where ir << int4multirange(int4range(100,200), int4range(400,500));
select count(*) from test_range_gist where ir >> int4multirange(int4range(100,200), int4range(400,500));
select count(*) from test_range_gist where ir &< int4multirange(int4range(100,200), int4range(400,500));
select count(*) from test_range_gist where ir &> int4multirange(int4range(100,200), int4range(400,500));
select count(*) from test_range_gist where ir -|- int4multirange(int4range(100,200), int4range(400,500));

-- test SP-GiST index that's been built incrementally
create table test_range_spgist(ir int4range);
create index test_range_spgist_idx on test_range_spgist using spgist (ir);

insert into test_range_spgist select int4range(g, g+10) from generate_series(1,2000) g;
insert into test_range_spgist select 'empty'::int4range from generate_series(1,500) g;
insert into test_range_spgist select int4range(g, g+10000) from generate_series(1,1000) g;
insert into test_range_spgist select 'empty'::int4range from generate_series(1,500) g;
insert into test_range_spgist select int4range(NULL,g*10,'(]') from generate_series(1,100) g;
insert into test_range_spgist select int4range(g*10,NULL,'(]') from generate_series(1,100) g;
insert into test_range_spgist select int4range(g, g+10) from generate_series(1,2000) g;

-- first, verify non-indexed results
SET enable_seqscan    = t;
SET enable_indexscan  = f;
SET enable_bitmapscan = f;

select count(*) from test_range_spgist where ir @> 'empty'::int4range;
select count(*) from test_range_spgist where ir = int4range(10,20);
select count(*) from test_range_spgist where ir @> 10;
select count(*) from test_range_spgist where ir @> int4range(10,20);
select count(*) from test_range_spgist where ir && int4range(10,20);
select count(*) from test_range_spgist where ir <@ int4range(10,50);
select count(*) from test_range_spgist where ir << int4range(100,500);
select count(*) from test_range_spgist where ir >> int4range(100,500);
select count(*) from test_range_spgist where ir &< int4range(100,500);
select count(*) from test_range_spgist where ir &> int4range(100,500);
select count(*) from test_range_spgist where ir -|- int4range(100,500);

-- now check same queries using index
SET enable_seqscan    = f;
SET enable_indexscan  = t;
SET enable_bitmapscan = f;

select count(*) from test_range_spgist where ir @> 'empty'::int4range;
select count(*) from test_range_spgist where ir = int4range(10,20);
select count(*) from test_range_spgist where ir @> 10;
select count(*) from test_range_spgist where ir @> int4range(10,20);
select count(*) from test_range_spgist where ir && int4range(10,20);
select count(*) from test_range_spgist where ir <@ int4range(10,50);
select count(*) from test_range_spgist where ir << int4range(100,500);
select count(*) from test_range_spgist where ir >> int4range(100,500);
select count(*) from test_range_spgist where ir &< int4range(100,500);
select count(*) from test_range_spgist where ir &> int4range(100,500);
select count(*) from test_range_spgist where ir -|- int4range(100,500);

-- now check same queries using a bulk-loaded index
drop index test_range_spgist_idx;
create index test_range_spgist_idx on test_range_spgist using spgist (ir);

select count(*) from test_range_spgist where ir @> 'empty'::int4range;
select count(*) from test_range_spgist where ir = int4range(10,20);
select count(*) from test_range_spgist where ir @> 10;
select count(*) from test_range_spgist where ir @> int4range(10,20);
select count(*) from test_range_spgist where ir && int4range(10,20);
select count(*) from test_range_spgist where ir <@ int4range(10,50);
select count(*) from test_range_spgist where ir << int4range(100,500);
select count(*) from test_range_spgist where ir >> int4range(100,500);
select count(*) from test_range_spgist where ir &< int4range(100,500);
select count(*) from test_range_spgist where ir &> int4range(100,500);
select count(*) from test_range_spgist where ir -|- int4range(100,500);

-- test index-only scans
explain (costs off)
select ir from test_range_spgist where ir -|- int4range(10,20) order by ir;
select ir from test_range_spgist where ir -|- int4range(10,20) order by ir;

RESET enable_seqscan;
RESET enable_indexscan;
RESET enable_bitmapscan;

-- test elem <@ range operator
create table test_range_elem(i int4);
create index test_range_elem_idx on test_range_elem (i);
insert into test_range_elem select i from generate_series(1,100) i;

SET enable_seqscan    = f;

select count(*) from test_range_elem where i <@ int4range(10,50);

-- also test spgist index on anyrange expression
create index on test_range_elem using spgist(int4range(i,i+10));
explain (costs off)
select count(*) from test_range_elem where int4range(i,i+10) <@ int4range(10,30);
select count(*) from test_range_elem where int4range(i,i+10) <@ int4range(10,30);

RESET enable_seqscan;

drop table test_range_elem;

--
-- Btree_gist is not included by default, so to test exclusion
-- constraints with range types, use singleton int ranges for the "="
-- portion of the constraint.
--

create table test_range_excl(
  room int4range,
  speaker int4range,
  during tsrange,
  exclude using gist (room with =, during with &&),
  exclude using gist (speaker with =, during with &&)
);

insert into test_range_excl
  values(int4range(123, 123, '[]'), int4range(1, 1, '[]'), '[2010-01-02 10:00, 2010-01-02 11:00)');
insert into test_range_excl
  values(int4range(123, 123, '[]'), int4range(2, 2, '[]'), '[2010-01-02 11:00, 2010-01-02 12:00)');
insert into test_range_excl
  values(int4range(123, 123, '[]'), int4range(3, 3, '[]'), '[2010-01-02 10:10, 2010-01-02 11:00)');
insert into test_range_excl
  values(int4range(124, 124, '[]'), int4range(3, 3, '[]'), '[2010-01-02 10:10, 2010-01-02 11:10)');
insert into test_range_excl
  values(int4range(125, 125, '[]'), int4range(1, 1, '[]'), '[2010-01-02 10:10, 2010-01-02 11:00)');

-- test bigint ranges
select int8range(10000000000::int8, 20000000000::int8,'(]');
-- test tstz ranges
set timezone to '-08';
select '[2010-01-01 01:00:00 -05, 2010-01-01 02:00:00 -08)'::tstzrange;
-- should fail
select '[2010-01-01 01:00:00 -08, 2010-01-01 02:00:00 -05)'::tstzrange;
set timezone to default;

--
-- Test user-defined range of floats
-- (type float8range was already made in test_setup.sql)
--

--should fail
create type bogus_float8range as range (subtype=float8, subtype_diff=float4mi);

select '[123.001, 5.e9)'::float8range @> 888.882::float8;
create table float8range_test(f8r float8range, i int);
insert into float8range_test values(float8range(-100.00007, '1.111113e9'), 42);
select * from float8range_test;
drop table float8range_test;

--
-- Test range types over domains
--

create domain mydomain as int4;
create type mydomainrange as range(subtype=mydomain);
select '[4,50)'::mydomainrange @> 7::mydomain;
drop domain mydomain;  -- fail
drop domain mydomain cascade;

--
-- Test domains over range types
--

create domain restrictedrange as int4range check (upper(value) < 10);
select '[4,5)'::restrictedrange @> 7;
select '[4,50)'::restrictedrange @> 7; -- should fail
drop domain restrictedrange;

--
-- Test multiple range types over the same subtype
--

create type textrange1 as range(subtype=text, collation="C");
create type textrange2 as range(subtype=text, collation="C");

select textrange1('a','Z') @> 'b'::text;
select textrange2('a','z') @> 'b'::text;

drop type textrange1;
drop type textrange2;

--
-- Test polymorphic type system
--

create function anyarray_anyrange_func(a anyarray, r anyrange)
  returns anyelement as 'select $1[1] + lower($2);' language sql;

select anyarray_anyrange_func(ARRAY[1,2], int4range(10,20));

-- should fail
select anyarray_anyrange_func(ARRAY[1,2], numrange(10,20));

drop function anyarray_anyrange_func(anyarray, anyrange);

-- should fail
create function bogus_func(anyelement)
  returns anyrange as 'select int4range(1,10)' language sql;

-- should fail
create function bogus_func(int)
  returns anyrange as 'select int4range(1,10)' language sql;

create function range_add_bounds(anyrange)
  returns anyelement as 'select lower($1) + upper($1)' language sql;

select range_add_bounds(int4range(1, 17));
select range_add_bounds(numrange(1.0001, 123.123));

create function rangetypes_sql(q anyrange, b anyarray, out c anyelement)
  as $$ select upper($1) + $2[1] $$
  language sql;

select rangetypes_sql(int4range(1,10), ARRAY[2,20]);
select rangetypes_sql(numrange(1,10), ARRAY[2,20]);  -- match failure

create function anycompatiblearray_anycompatiblerange_func(a anycompatiblearray, r anycompatiblerange)
  returns anycompatible as 'select $1[1] + lower($2);' language sql;

select anycompatiblearray_anycompatiblerange_func(ARRAY[1,2], int4range(10,20));

select anycompatiblearray_anycompatiblerange_func(ARRAY[1,2], numrange(10,20));

-- should fail
select anycompatiblearray_anycompatiblerange_func(ARRAY[1.1,2], int4range(10,20));

drop function anycompatiblearray_anycompatiblerange_func(anycompatiblearray, anycompatiblerange);

-- should fail
create function bogus_func(anycompatible)
  returns anycompatiblerange as 'select int4range(1,10)' language sql;

--
-- Arrays of ranges
--

select ARRAY[numrange(1.1, 1.2), numrange(12.3, 155.5)];

create table i8r_array (f1 int, f2 int8range[]);
insert into i8r_array values (42, array[int8range(1,10), int8range(2,20)]);
select * from i8r_array;
drop table i8r_array;

--
-- Ranges of arrays
--

create type arrayrange as range (subtype=int4[]);

select arrayrange(ARRAY[1,2], ARRAY[2,1]);
select arrayrange(ARRAY[2,1], ARRAY[1,2]);  -- fail

select array[1,1] <@ arrayrange(array[1,2], array[2,1]);
select array[1,3] <@ arrayrange(array[1,2], array[2,1]);

--
-- Ranges of composites
--

create type two_ints as (a int, b int);
create type two_ints_range as range (subtype = two_ints);

-- with force_parallel_mode on, this exercises tqueue.c's range remapping
select *, row_to_json(upper(t)) as u from
  (values (two_ints_range(row(1,2), row(3,4))),
          (two_ints_range(row(5,6), row(7,8)))) v(t);

-- this must be rejected to avoid self-inclusion issues:
alter type two_ints add attribute c two_ints_range;

drop type two_ints cascade;

--
-- Check behavior when subtype lacks a hash function
--

create type cashrange as range (subtype = money);

set enable_sort = off;  -- try to make it pick a hash setop implementation

select '(2,5)'::cashrange except select '(5,6)'::cashrange;

reset enable_sort;

--
-- OUT/INOUT/TABLE functions
--

-- infer anyrange from anyrange
create function outparam_succeed(i anyrange, out r anyrange, out t text)
  as $$ select $1, 'foo'::text $$ language sql;

select * from outparam_succeed(int4range(1,2));

create function outparam2_succeed(r anyrange, out lu anyarray, out ul anyarray)
  as $$ select array[lower($1), upper($1)], array[upper($1), lower($1)] $$
  language sql;

select * from outparam2_succeed(int4range(1,11));

-- infer anyarray from anyrange
create function outparam_succeed2(i anyrange, out r anyarray, out t text)
  as $$ select ARRAY[upper($1)], 'foo'::text $$ language sql;

select * from outparam_succeed2(int4range(int4range(1,2)));

-- infer anyelement from anyrange
create function inoutparam_succeed(out i anyelement, inout r anyrange)
  as $$ select upper($1), $1 $$ language sql;

select * from inoutparam_succeed(int4range(1,2));

create function table_succeed(r anyrange)
  returns table(l anyelement, u anyelement)
  as $$ select lower($1), upper($1) $$
  language sql;

select * from table_succeed(int4range(1,11));

-- should fail
create function outparam_fail(i anyelement, out r anyrange, out t text)
  as $$ select '[1,10]', 'foo' $$ language sql;

--should fail
create function inoutparam_fail(inout i anyelement, out r anyrange)
  as $$ select $1, '[1,10]' $$ language sql;

--should fail
create function table_fail(i anyelement) returns table(i anyelement, r anyrange)
  as $$ select $1, '[1,10]' $$ language sql;