1--
2-- TIMESTAMP
3--
4
5CREATE TABLE TIMESTAMP_TBL (d1 timestamp(2) without time zone);
6
7-- Test shorthand input values
8-- We can't just "select" the results since they aren't constants; test for
9-- equality instead.  We can do that by running the test inside a transaction
10-- block, within which the value of 'now' shouldn't change, and so these
11-- related values shouldn't either.
12
13BEGIN;
14
15INSERT INTO TIMESTAMP_TBL VALUES ('today');
16INSERT INTO TIMESTAMP_TBL VALUES ('yesterday');
17INSERT INTO TIMESTAMP_TBL VALUES ('tomorrow');
18-- time zone should be ignored by this data type
19INSERT INTO TIMESTAMP_TBL VALUES ('tomorrow EST');
20INSERT INTO TIMESTAMP_TBL VALUES ('tomorrow zulu');
21
22SELECT count(*) AS One FROM TIMESTAMP_TBL WHERE d1 = timestamp without time zone 'today';
23SELECT count(*) AS Three FROM TIMESTAMP_TBL WHERE d1 = timestamp without time zone 'tomorrow';
24SELECT count(*) AS One FROM TIMESTAMP_TBL WHERE d1 = timestamp without time zone 'yesterday';
25
26COMMIT;
27
28DELETE FROM TIMESTAMP_TBL;
29
30-- Verify that 'now' *does* change over a reasonable interval such as 100 msec,
31-- and that it doesn't change over the same interval within a transaction block
32
33INSERT INTO TIMESTAMP_TBL VALUES ('now');
34SELECT pg_sleep(0.1);
35
36BEGIN;
37INSERT INTO TIMESTAMP_TBL VALUES ('now');
38SELECT pg_sleep(0.1);
39INSERT INTO TIMESTAMP_TBL VALUES ('now');
40SELECT pg_sleep(0.1);
41SELECT count(*) AS two FROM TIMESTAMP_TBL WHERE d1 = timestamp(2) without time zone 'now';
42SELECT count(d1) AS three, count(DISTINCT d1) AS two FROM TIMESTAMP_TBL;
43COMMIT;
44
45TRUNCATE TIMESTAMP_TBL;
46
47-- Special values
48INSERT INTO TIMESTAMP_TBL VALUES ('-infinity');
49INSERT INTO TIMESTAMP_TBL VALUES ('infinity');
50INSERT INTO TIMESTAMP_TBL VALUES ('epoch');
51-- Obsolete special values
52INSERT INTO TIMESTAMP_TBL VALUES ('invalid');
53INSERT INTO TIMESTAMP_TBL VALUES ('undefined');
54INSERT INTO TIMESTAMP_TBL VALUES ('current');
55
56-- Postgres v6.0 standard output format
57INSERT INTO TIMESTAMP_TBL VALUES ('Mon Feb 10 17:32:01 1997 PST');
58
59-- Variations on Postgres v6.1 standard output format
60INSERT INTO TIMESTAMP_TBL VALUES ('Mon Feb 10 17:32:01.000001 1997 PST');
61INSERT INTO TIMESTAMP_TBL VALUES ('Mon Feb 10 17:32:01.999999 1997 PST');
62INSERT INTO TIMESTAMP_TBL VALUES ('Mon Feb 10 17:32:01.4 1997 PST');
63INSERT INTO TIMESTAMP_TBL VALUES ('Mon Feb 10 17:32:01.5 1997 PST');
64INSERT INTO TIMESTAMP_TBL VALUES ('Mon Feb 10 17:32:01.6 1997 PST');
65
66-- ISO 8601 format
67INSERT INTO TIMESTAMP_TBL VALUES ('1997-01-02');
68INSERT INTO TIMESTAMP_TBL VALUES ('1997-01-02 03:04:05');
69INSERT INTO TIMESTAMP_TBL VALUES ('1997-02-10 17:32:01-08');
70INSERT INTO TIMESTAMP_TBL VALUES ('1997-02-10 17:32:01-0800');
71INSERT INTO TIMESTAMP_TBL VALUES ('1997-02-10 17:32:01 -08:00');
72INSERT INTO TIMESTAMP_TBL VALUES ('19970210 173201 -0800');
73INSERT INTO TIMESTAMP_TBL VALUES ('1997-06-10 17:32:01 -07:00');
74INSERT INTO TIMESTAMP_TBL VALUES ('2001-09-22T18:19:20');
75
76-- POSIX format (note that the timezone abbrev is just decoration here)
77INSERT INTO TIMESTAMP_TBL VALUES ('2000-03-15 08:14:01 GMT+8');
78INSERT INTO TIMESTAMP_TBL VALUES ('2000-03-15 13:14:02 GMT-1');
79INSERT INTO TIMESTAMP_TBL VALUES ('2000-03-15 12:14:03 GMT-2');
80INSERT INTO TIMESTAMP_TBL VALUES ('2000-03-15 03:14:04 PST+8');
81INSERT INTO TIMESTAMP_TBL VALUES ('2000-03-15 02:14:05 MST+7:00');
82
83-- Variations for acceptable input formats
84INSERT INTO TIMESTAMP_TBL VALUES ('Feb 10 17:32:01 1997 -0800');
85INSERT INTO TIMESTAMP_TBL VALUES ('Feb 10 17:32:01 1997');
86INSERT INTO TIMESTAMP_TBL VALUES ('Feb 10 5:32PM 1997');
87INSERT INTO TIMESTAMP_TBL VALUES ('1997/02/10 17:32:01-0800');
88INSERT INTO TIMESTAMP_TBL VALUES ('1997-02-10 17:32:01 PST');
89INSERT INTO TIMESTAMP_TBL VALUES ('Feb-10-1997 17:32:01 PST');
90INSERT INTO TIMESTAMP_TBL VALUES ('02-10-1997 17:32:01 PST');
91INSERT INTO TIMESTAMP_TBL VALUES ('19970210 173201 PST');
92set datestyle to ymd;
93INSERT INTO TIMESTAMP_TBL VALUES ('97FEB10 5:32:01PM UTC');
94INSERT INTO TIMESTAMP_TBL VALUES ('97/02/10 17:32:01 UTC');
95reset datestyle;
96INSERT INTO TIMESTAMP_TBL VALUES ('1997.041 17:32:01 UTC');
97INSERT INTO TIMESTAMP_TBL VALUES ('19970210 173201 America/New_York');
98-- this fails (even though TZ is a no-op, we still look it up)
99INSERT INTO TIMESTAMP_TBL VALUES ('19970710 173201 America/Does_not_exist');
100
101-- Check date conversion and date arithmetic
102INSERT INTO TIMESTAMP_TBL VALUES ('1997-06-10 18:32:01 PDT');
103
104INSERT INTO TIMESTAMP_TBL VALUES ('Feb 10 17:32:01 1997');
105INSERT INTO TIMESTAMP_TBL VALUES ('Feb 11 17:32:01 1997');
106INSERT INTO TIMESTAMP_TBL VALUES ('Feb 12 17:32:01 1997');
107INSERT INTO TIMESTAMP_TBL VALUES ('Feb 13 17:32:01 1997');
108INSERT INTO TIMESTAMP_TBL VALUES ('Feb 14 17:32:01 1997');
109INSERT INTO TIMESTAMP_TBL VALUES ('Feb 15 17:32:01 1997');
110INSERT INTO TIMESTAMP_TBL VALUES ('Feb 16 17:32:01 1997');
111
112INSERT INTO TIMESTAMP_TBL VALUES ('Feb 16 17:32:01 0097 BC');
113INSERT INTO TIMESTAMP_TBL VALUES ('Feb 16 17:32:01 0097');
114INSERT INTO TIMESTAMP_TBL VALUES ('Feb 16 17:32:01 0597');
115INSERT INTO TIMESTAMP_TBL VALUES ('Feb 16 17:32:01 1097');
116INSERT INTO TIMESTAMP_TBL VALUES ('Feb 16 17:32:01 1697');
117INSERT INTO TIMESTAMP_TBL VALUES ('Feb 16 17:32:01 1797');
118INSERT INTO TIMESTAMP_TBL VALUES ('Feb 16 17:32:01 1897');
119INSERT INTO TIMESTAMP_TBL VALUES ('Feb 16 17:32:01 1997');
120INSERT INTO TIMESTAMP_TBL VALUES ('Feb 16 17:32:01 2097');
121
122INSERT INTO TIMESTAMP_TBL VALUES ('Feb 28 17:32:01 1996');
123INSERT INTO TIMESTAMP_TBL VALUES ('Feb 29 17:32:01 1996');
124INSERT INTO TIMESTAMP_TBL VALUES ('Mar 01 17:32:01 1996');
125INSERT INTO TIMESTAMP_TBL VALUES ('Dec 30 17:32:01 1996');
126INSERT INTO TIMESTAMP_TBL VALUES ('Dec 31 17:32:01 1996');
127INSERT INTO TIMESTAMP_TBL VALUES ('Jan 01 17:32:01 1997');
128INSERT INTO TIMESTAMP_TBL VALUES ('Feb 28 17:32:01 1997');
129INSERT INTO TIMESTAMP_TBL VALUES ('Feb 29 17:32:01 1997');
130INSERT INTO TIMESTAMP_TBL VALUES ('Mar 01 17:32:01 1997');
131INSERT INTO TIMESTAMP_TBL VALUES ('Dec 30 17:32:01 1997');
132INSERT INTO TIMESTAMP_TBL VALUES ('Dec 31 17:32:01 1997');
133INSERT INTO TIMESTAMP_TBL VALUES ('Dec 31 17:32:01 1999');
134INSERT INTO TIMESTAMP_TBL VALUES ('Jan 01 17:32:01 2000');
135INSERT INTO TIMESTAMP_TBL VALUES ('Dec 31 17:32:01 2000');
136INSERT INTO TIMESTAMP_TBL VALUES ('Jan 01 17:32:01 2001');
137
138-- Currently unsupported syntax and ranges
139INSERT INTO TIMESTAMP_TBL VALUES ('Feb 16 17:32:01 -0097');
140INSERT INTO TIMESTAMP_TBL VALUES ('Feb 16 17:32:01 5097 BC');
141
142SELECT '' AS "64", d1 FROM TIMESTAMP_TBL;
143
144-- Check behavior at the lower boundary of the timestamp range
145SELECT '4714-11-24 00:00:00 BC'::timestamp;
146SELECT '4714-11-23 23:59:59 BC'::timestamp;  -- out of range
147-- The upper boundary differs between integer and float timestamps, so no check
148
149-- Demonstrate functions and operators
150SELECT '' AS "48", d1 FROM TIMESTAMP_TBL
151   WHERE d1 > timestamp without time zone '1997-01-02';
152
153SELECT '' AS "15", d1 FROM TIMESTAMP_TBL
154   WHERE d1 < timestamp without time zone '1997-01-02';
155
156SELECT '' AS one, d1 FROM TIMESTAMP_TBL
157   WHERE d1 = timestamp without time zone '1997-01-02';
158
159SELECT '' AS "63", d1 FROM TIMESTAMP_TBL
160   WHERE d1 != timestamp without time zone '1997-01-02';
161
162SELECT '' AS "16", d1 FROM TIMESTAMP_TBL
163   WHERE d1 <= timestamp without time zone '1997-01-02';
164
165SELECT '' AS "49", d1 FROM TIMESTAMP_TBL
166   WHERE d1 >= timestamp without time zone '1997-01-02';
167
168SELECT '' AS "54", d1 - timestamp without time zone '1997-01-02' AS diff
169   FROM TIMESTAMP_TBL WHERE d1 BETWEEN '1902-01-01' AND '2038-01-01';
170
171SELECT '' AS date_trunc_week, date_trunc( 'week', timestamp '2004-02-29 15:44:17.71393' ) AS week_trunc;
172
173-- Test casting within a BETWEEN qualifier
174SELECT '' AS "54", d1 - timestamp without time zone '1997-01-02' AS diff
175  FROM TIMESTAMP_TBL
176  WHERE d1 BETWEEN timestamp without time zone '1902-01-01'
177   AND timestamp without time zone '2038-01-01';
178
179-- DATE_PART (timestamp_part)
180SELECT d1 as "timestamp",
181   date_part( 'year', d1) AS year, date_part( 'month', d1) AS month,
182   date_part( 'day', d1) AS day, date_part( 'hour', d1) AS hour,
183   date_part( 'minute', d1) AS minute, date_part( 'second', d1) AS second
184   FROM TIMESTAMP_TBL;
185
186SELECT d1 as "timestamp",
187   date_part( 'quarter', d1) AS quarter, date_part( 'msec', d1) AS msec,
188   date_part( 'usec', d1) AS usec
189   FROM TIMESTAMP_TBL;
190
191SELECT d1 as "timestamp",
192   date_part( 'isoyear', d1) AS isoyear, date_part( 'week', d1) AS week,
193   date_part( 'isodow', d1) AS isodow, date_part( 'dow', d1) AS dow,
194   date_part( 'doy', d1) AS doy
195   FROM TIMESTAMP_TBL;
196
197SELECT d1 as "timestamp",
198   date_part( 'decade', d1) AS decade,
199   date_part( 'century', d1) AS century,
200   date_part( 'millennium', d1) AS millennium,
201   round(date_part( 'julian', d1)) AS julian
202   FROM TIMESTAMP_TBL;
203
204-- TO_CHAR()
205SELECT '' AS to_char_1, to_char(d1, 'DAY Day day DY Dy dy MONTH Month month RM MON Mon mon')
206   FROM TIMESTAMP_TBL;
207
208SELECT '' AS to_char_2, to_char(d1, 'FMDAY FMDay FMday FMMONTH FMMonth FMmonth FMRM')
209   FROM TIMESTAMP_TBL;
210
211SELECT '' AS to_char_3, to_char(d1, 'Y,YYY YYYY YYY YY Y CC Q MM WW DDD DD D J')
212   FROM TIMESTAMP_TBL;
213
214SELECT '' AS to_char_4, to_char(d1, 'FMY,YYY FMYYYY FMYYY FMYY FMY FMCC FMQ FMMM FMWW FMDDD FMDD FMD FMJ')
215   FROM TIMESTAMP_TBL;
216
217SELECT '' AS to_char_5, to_char(d1, 'HH HH12 HH24 MI SS SSSS')
218   FROM TIMESTAMP_TBL;
219
220SELECT '' AS to_char_6, to_char(d1, E'"HH:MI:SS is" HH:MI:SS "\\"text between quote marks\\""')
221   FROM TIMESTAMP_TBL;
222
223SELECT '' AS to_char_7, to_char(d1, 'HH24--text--MI--text--SS')
224   FROM TIMESTAMP_TBL;
225
226SELECT '' AS to_char_8, to_char(d1, 'YYYYTH YYYYth Jth')
227   FROM TIMESTAMP_TBL;
228
229SELECT '' AS to_char_9, to_char(d1, 'YYYY A.D. YYYY a.d. YYYY bc HH:MI:SS P.M. HH:MI:SS p.m. HH:MI:SS pm')
230   FROM TIMESTAMP_TBL;
231
232SELECT '' AS to_char_10, to_char(d1, 'IYYY IYY IY I IW IDDD ID')
233   FROM TIMESTAMP_TBL;
234
235SELECT '' AS to_char_11, to_char(d1, 'FMIYYY FMIYY FMIY FMI FMIW FMIDDD FMID')
236   FROM TIMESTAMP_TBL;
237
238-- Roman months, with upper and lower case.
239SELECT i,
240       to_char(i * interval '1mon', 'rm'),
241       to_char(i * interval '1mon', 'RM')
242    FROM generate_series(-13, 13) i;
243
244-- timestamp numeric fields constructor
245SELECT make_timestamp(2014,12,28,6,30,45.887);
246