1--
2-- INTERVAL
3--
4
5SET DATESTYLE = 'ISO';
6SET IntervalStyle to postgres;
7
8-- check acceptance of "time zone style"
9SELECT INTERVAL '01:00' AS "One hour";
10SELECT INTERVAL '+02:00' AS "Two hours";
11SELECT INTERVAL '-08:00' AS "Eight hours";
12SELECT INTERVAL '-1 +02:03' AS "22 hours ago...";
13SELECT INTERVAL '-1 days +02:03' AS "22 hours ago...";
14SELECT INTERVAL '1.5 weeks' AS "Ten days twelve hours";
15SELECT INTERVAL '1.5 months' AS "One month 15 days";
16SELECT INTERVAL '10 years -11 month -12 days +13:14' AS "9 years...";
17
18CREATE TABLE INTERVAL_TBL (f1 interval);
19
20INSERT INTO INTERVAL_TBL (f1) VALUES ('@ 1 minute');
21INSERT INTO INTERVAL_TBL (f1) VALUES ('@ 5 hour');
22INSERT INTO INTERVAL_TBL (f1) VALUES ('@ 10 day');
23INSERT INTO INTERVAL_TBL (f1) VALUES ('@ 34 year');
24INSERT INTO INTERVAL_TBL (f1) VALUES ('@ 3 months');
25INSERT INTO INTERVAL_TBL (f1) VALUES ('@ 14 seconds ago');
26INSERT INTO INTERVAL_TBL (f1) VALUES ('1 day 2 hours 3 minutes 4 seconds');
27INSERT INTO INTERVAL_TBL (f1) VALUES ('6 years');
28INSERT INTO INTERVAL_TBL (f1) VALUES ('5 months');
29INSERT INTO INTERVAL_TBL (f1) VALUES ('5 months 12 hours');
30
31-- badly formatted interval
32INSERT INTO INTERVAL_TBL (f1) VALUES ('badly formatted interval');
33INSERT INTO INTERVAL_TBL (f1) VALUES ('@ 30 eons ago');
34
35-- test interval operators
36
37SELECT '' AS ten, * FROM INTERVAL_TBL;
38
39SELECT '' AS nine, * FROM INTERVAL_TBL
40   WHERE INTERVAL_TBL.f1 <> interval '@ 10 days';
41
42SELECT '' AS three, * FROM INTERVAL_TBL
43   WHERE INTERVAL_TBL.f1 <= interval '@ 5 hours';
44
45SELECT '' AS three, * FROM INTERVAL_TBL
46   WHERE INTERVAL_TBL.f1 < interval '@ 1 day';
47
48SELECT '' AS one, * FROM INTERVAL_TBL
49   WHERE INTERVAL_TBL.f1 = interval '@ 34 years';
50
51SELECT '' AS five, * FROM INTERVAL_TBL
52   WHERE INTERVAL_TBL.f1 >= interval '@ 1 month';
53
54SELECT '' AS nine, * FROM INTERVAL_TBL
55   WHERE INTERVAL_TBL.f1 > interval '@ 3 seconds ago';
56
57SELECT '' AS fortyfive, r1.*, r2.*
58   FROM INTERVAL_TBL r1, INTERVAL_TBL r2
59   WHERE r1.f1 > r2.f1
60   ORDER BY r1.f1, r2.f1;
61
62-- Test intervals that are large enough to overflow 64 bits in comparisons
63CREATE TEMP TABLE INTERVAL_TBL_OF (f1 interval);
64INSERT INTO INTERVAL_TBL_OF (f1) VALUES
65  ('2147483647 days 2147483647 months'),
66  ('2147483647 days -2147483648 months'),
67  ('1 year'),
68  ('-2147483648 days 2147483647 months'),
69  ('-2147483648 days -2147483648 months');
70-- these should fail as out-of-range
71INSERT INTO INTERVAL_TBL_OF (f1) VALUES ('2147483648 days');
72INSERT INTO INTERVAL_TBL_OF (f1) VALUES ('-2147483649 days');
73INSERT INTO INTERVAL_TBL_OF (f1) VALUES ('2147483647 years');
74INSERT INTO INTERVAL_TBL_OF (f1) VALUES ('-2147483648 years');
75
76SELECT r1.*, r2.*
77   FROM INTERVAL_TBL_OF r1, INTERVAL_TBL_OF r2
78   WHERE r1.f1 > r2.f1
79   ORDER BY r1.f1, r2.f1;
80
81CREATE INDEX ON INTERVAL_TBL_OF USING btree (f1);
82SET enable_seqscan TO false;
83EXPLAIN (COSTS OFF)
84SELECT f1 FROM INTERVAL_TBL_OF r1 ORDER BY f1;
85SELECT f1 FROM INTERVAL_TBL_OF r1 ORDER BY f1;
86RESET enable_seqscan;
87
88DROP TABLE INTERVAL_TBL_OF;
89
90-- Test multiplication and division with intervals.
91-- Floating point arithmetic rounding errors can lead to unexpected results,
92-- though the code attempts to do the right thing and round up to days and
93-- minutes to avoid results such as '3 days 24:00 hours' or '14:20:60'.
94-- Note that it is expected for some day components to be greater than 29 and
95-- some time components be greater than 23:59:59 due to how intervals are
96-- stored internally.
97
98CREATE TABLE INTERVAL_MULDIV_TBL (span interval);
99COPY INTERVAL_MULDIV_TBL FROM STDIN;
10041 mon 12 days 360:00
101-41 mon -12 days +360:00
102-12 days
1039 mon -27 days 12:34:56
104-3 years 482 days 76:54:32.189
1054 mon
10614 mon
107999 mon 999 days
108\.
109
110SELECT span * 0.3 AS product
111FROM INTERVAL_MULDIV_TBL;
112
113SELECT span * 8.2 AS product
114FROM INTERVAL_MULDIV_TBL;
115
116SELECT span / 10 AS quotient
117FROM INTERVAL_MULDIV_TBL;
118
119SELECT span / 100 AS quotient
120FROM INTERVAL_MULDIV_TBL;
121
122DROP TABLE INTERVAL_MULDIV_TBL;
123
124SET DATESTYLE = 'postgres';
125SET IntervalStyle to postgres_verbose;
126
127SELECT '' AS ten, * FROM INTERVAL_TBL;
128
129-- test avg(interval), which is somewhat fragile since people have been
130-- known to change the allowed input syntax for type interval without
131-- updating pg_aggregate.agginitval
132
133select avg(f1) from interval_tbl;
134
135-- test long interval input
136select '4 millenniums 5 centuries 4 decades 1 year 4 months 4 days 17 minutes 31 seconds'::interval;
137
138-- test long interval output
139-- Note: the actual maximum length of the interval output is longer,
140-- but we need the test to work for both integer and floating-point
141-- timestamps.
142select '100000000y 10mon -1000000000d -100000h -10min -10.000001s ago'::interval;
143
144-- test justify_hours() and justify_days()
145
146SELECT justify_hours(interval '6 months 3 days 52 hours 3 minutes 2 seconds') as "6 mons 5 days 4 hours 3 mins 2 seconds";
147SELECT justify_days(interval '6 months 36 days 5 hours 4 minutes 3 seconds') as "7 mons 6 days 5 hours 4 mins 3 seconds";
148
149-- test justify_interval()
150
151SELECT justify_interval(interval '1 month -1 hour') as "1 month -1 hour";
152
153-- test fractional second input, and detection of duplicate units
154SET DATESTYLE = 'ISO';
155SET IntervalStyle TO postgres;
156
157SELECT '1 millisecond'::interval, '1 microsecond'::interval,
158       '500 seconds 99 milliseconds 51 microseconds'::interval;
159SELECT '3 days 5 milliseconds'::interval;
160
161SELECT '1 second 2 seconds'::interval;              -- error
162SELECT '10 milliseconds 20 milliseconds'::interval; -- error
163SELECT '5.5 seconds 3 milliseconds'::interval;      -- error
164SELECT '1:20:05 5 microseconds'::interval;          -- error
165SELECT '1 day 1 day'::interval;                     -- error
166SELECT interval '1-2';  -- SQL year-month literal
167SELECT interval '999' second;  -- oversize leading field is ok
168SELECT interval '999' minute;
169SELECT interval '999' hour;
170SELECT interval '999' day;
171SELECT interval '999' month;
172
173-- test SQL-spec syntaxes for restricted field sets
174SELECT interval '1' year;
175SELECT interval '2' month;
176SELECT interval '3' day;
177SELECT interval '4' hour;
178SELECT interval '5' minute;
179SELECT interval '6' second;
180SELECT interval '1' year to month;
181SELECT interval '1-2' year to month;
182SELECT interval '1 2' day to hour;
183SELECT interval '1 2:03' day to hour;
184SELECT interval '1 2:03:04' day to hour;
185SELECT interval '1 2' day to minute;
186SELECT interval '1 2:03' day to minute;
187SELECT interval '1 2:03:04' day to minute;
188SELECT interval '1 2' day to second;
189SELECT interval '1 2:03' day to second;
190SELECT interval '1 2:03:04' day to second;
191SELECT interval '1 2' hour to minute;
192SELECT interval '1 2:03' hour to minute;
193SELECT interval '1 2:03:04' hour to minute;
194SELECT interval '1 2' hour to second;
195SELECT interval '1 2:03' hour to second;
196SELECT interval '1 2:03:04' hour to second;
197SELECT interval '1 2' minute to second;
198SELECT interval '1 2:03' minute to second;
199SELECT interval '1 2:03:04' minute to second;
200SELECT interval '1 +2:03' minute to second;
201SELECT interval '1 +2:03:04' minute to second;
202SELECT interval '1 -2:03' minute to second;
203SELECT interval '1 -2:03:04' minute to second;
204SELECT interval '123 11' day to hour; -- ok
205SELECT interval '123 11' day; -- not ok
206SELECT interval '123 11'; -- not ok, too ambiguous
207SELECT interval '123 2:03 -2:04'; -- not ok, redundant hh:mm fields
208
209-- test syntaxes for restricted precision
210SELECT interval(0) '1 day 01:23:45.6789';
211SELECT interval(2) '1 day 01:23:45.6789';
212SELECT interval '12:34.5678' minute to second(2);  -- per SQL spec
213SELECT interval '1.234' second;
214SELECT interval '1.234' second(2);
215SELECT interval '1 2.345' day to second(2);
216SELECT interval '1 2:03' day to second(2);
217SELECT interval '1 2:03.4567' day to second(2);
218SELECT interval '1 2:03:04.5678' day to second(2);
219SELECT interval '1 2.345' hour to second(2);
220SELECT interval '1 2:03.45678' hour to second(2);
221SELECT interval '1 2:03:04.5678' hour to second(2);
222SELECT interval '1 2.3456' minute to second(2);
223SELECT interval '1 2:03.5678' minute to second(2);
224SELECT interval '1 2:03:04.5678' minute to second(2);
225
226-- test casting to restricted precision (bug #14479)
227SELECT f1, f1::INTERVAL DAY TO MINUTE AS "minutes",
228  (f1 + INTERVAL '1 month')::INTERVAL MONTH::INTERVAL YEAR AS "years"
229  FROM interval_tbl;
230
231-- test inputting and outputting SQL standard interval literals
232SET IntervalStyle TO sql_standard;
233SELECT  interval '0'                       AS "zero",
234        interval '1-2' year to month       AS "year-month",
235        interval '1 2:03:04' day to second AS "day-time",
236        - interval '1-2'                   AS "negative year-month",
237        - interval '1 2:03:04'             AS "negative day-time";
238
239-- test input of some not-quite-standard interval values in the sql style
240SET IntervalStyle TO postgres;
241SELECT  interval '+1 -1:00:00',
242        interval '-1 +1:00:00',
243        interval '+1-2 -3 +4:05:06.789',
244        interval '-1-2 +3 -4:05:06.789';
245
246-- test output of couple non-standard interval values in the sql style
247SET IntervalStyle TO sql_standard;
248SELECT  interval '1 day -1 hours',
249        interval '-1 days +1 hours',
250        interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds',
251        - interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds';
252
253-- test outputting iso8601 intervals
254SET IntervalStyle to iso_8601;
255select  interval '0'                                AS "zero",
256        interval '1-2'                              AS "a year 2 months",
257        interval '1 2:03:04'                        AS "a bit over a day",
258        interval '2:03:04.45679'                    AS "a bit over 2 hours",
259        (interval '1-2' + interval '3 4:05:06.7')   AS "all fields",
260        (interval '1-2' - interval '3 4:05:06.7')   AS "mixed sign",
261        (- interval '1-2' + interval '3 4:05:06.7') AS "negative";
262
263-- test inputting ISO 8601 4.4.2.1 "Format With Time Unit Designators"
264SET IntervalStyle to sql_standard;
265select  interval 'P0Y'                    AS "zero",
266        interval 'P1Y2M'                  AS "a year 2 months",
267        interval 'P1W'                    AS "a week",
268        interval 'P1DT2H3M4S'             AS "a bit over a day",
269        interval 'P1Y2M3DT4H5M6.7S'       AS "all fields",
270        interval 'P-1Y-2M-3DT-4H-5M-6.7S' AS "negative",
271        interval 'PT-0.1S'                AS "fractional second";
272
273-- test inputting ISO 8601 4.4.2.2 "Alternative Format"
274SET IntervalStyle to postgres;
275select  interval 'P00021015T103020'       AS "ISO8601 Basic Format",
276        interval 'P0002-10-15T10:30:20'   AS "ISO8601 Extended Format";
277
278-- Make sure optional ISO8601 alternative format fields are optional.
279select  interval 'P0002'                  AS "year only",
280        interval 'P0002-10'               AS "year month",
281        interval 'P0002-10-15'            AS "year month day",
282        interval 'P0002T1S'               AS "year only plus time",
283        interval 'P0002-10T1S'            AS "year month plus time",
284        interval 'P0002-10-15T1S'         AS "year month day plus time",
285        interval 'PT10'                   AS "hour only",
286        interval 'PT10:30'                AS "hour minute";
287
288-- test a couple rounding cases that changed since 8.3 w/ HAVE_INT64_TIMESTAMP.
289SET IntervalStyle to postgres_verbose;
290select interval '-10 mons -3 days +03:55:06.70';
291select interval '1 year 2 mons 3 days 04:05:06.699999';
292select interval '0:0:0.7', interval '@ 0.70 secs', interval '0.7 seconds';
293
294-- check that '30 days' equals '1 month' according to the hash function
295select '30 days'::interval = '1 month'::interval as t;
296select interval_hash('30 days'::interval) = interval_hash('1 month'::interval) as t;
297
298-- numeric constructor
299select make_interval(years := 2);
300select make_interval(years := 1, months := 6);
301select make_interval(years := 1, months := -1, weeks := 5, days := -7, hours := 25, mins := -180);
302
303select make_interval() = make_interval(years := 0, months := 0, weeks := 0, days := 0, mins := 0, secs := 0.0);
304select make_interval(hours := -2, mins := -10, secs := -25.3);
305
306select make_interval(years := 'inf'::float::int);
307select make_interval(months := 'NaN'::float::int);
308select make_interval(secs := 'inf');
309select make_interval(secs := 'NaN');
310select make_interval(secs := 7e12);
311