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
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
1329
1330
1331
1332
1333
1334
1335
1336
1337
1338
1339
1340
1341
1342
1343
1344
1345
1346
1347
1348
1349
1350
1351
1352
1353
1354
1355
1356
1357
1358
1359
1360
1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372
1373
1374
1375
1376
1377
1378
1379
1380
1381
1382
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
1401
1402
1403
1404
1405
1406
1407
1408
1409
1410
1411
1412
1413
1414
1415
1416
1417
1418
1419
1420
1421
1422
1423
1424
1425
1426
1427
1428
1429
1430
1431
1432
1433
1434
1435
1436
1437
1438
1439
1440
1441
1442
1443
1444
1445
1446
1447
1448
1449
1450
1451
1452
1453
1454
1455
1456
1457
1458
1459
1460
1461
1462
1463
1464
1465
1466
1467
1468
1469
1470
1471
1472
1473
1474
1475
1476
1477
1478
1479
1480
1481
1482
1483
1484
1485
1486
1487
1488
1489
1490
1491
1492
1493
1494
1495
1496
1497
1498
1499
1500
1501
1502
1503
1504
1505
1506
1507
1508
1509
1510
1511
1512
1513
1514
1515
1516
1517
1518
1519
1520
1521
1522
1523
1524
1525
1526
1527
1528
1529
1530
1531
1532
1533
1534
1535
1536
1537
1538
1539
1540
1541
1542
1543
1544
1545
1546
1547
1548
1549
1550
1551
1552
1553
1554
1555
1556
1557
1558
1559
1560
1561
1562
1563
1564
1565
1566
1567
1568
1569
1570
1571
1572
1573
1574
1575
1576
1577
1578
1579
1580
1581
1582
1583
1584
1585
1586
1587
1588
1589
1590
1591
1592
1593
1594
1595
1596
1597
1598
1599
1600
1601
1602
1603
1604
1605
1606
1607
1608
1609
1610
1611
1612
1613
1614
1615
1616
1617
1618
1619
1620
1621
1622
1623
1624
1625
1626
1627
1628
1629
1630
1631
1632
1633
1634
1635
1636
1637
1638
1639
1640
1641
1642
1643
1644
1645
1646
1647
1648
1649
1650
1651
1652
1653
1654
1655
1656
1657
1658
1659
1660
1661
1662
1663
1664
1665
1666
1667
1668
1669
1670
1671
1672
1673
1674
1675
1676
1677
1678
1679
1680
1681
1682
1683
1684
1685
1686
1687
1688
1689
1690
1691
1692
1693
1694
1695
1696
1697
1698
1699
1700
1701
1702
1703
1704
1705
1706
1707
1708
1709
1710
1711
1712
1713
1714
1715
1716
1717
1718
1719
1720
1721
1722
1723
1724
1725
1726
1727
1728
1729
1730
1731
1732
1733
1734
1735
1736
1737
1738
1739
1740
1741
1742
1743
1744
1745
1746
1747
1748
1749
1750
1751
1752
1753
1754
1755
1756
1757
1758
1759
1760
1761
1762
1763
1764
1765
1766
1767
1768
1769
1770
1771
1772
1773
1774
1775
1776
1777
1778
1779
1780
1781
1782
1783
1784
1785
1786
1787
1788
1789
1790
1791
1792
1793
1794
1795
1796
1797
1798
1799
1800
1801
1802
1803
1804
1805
1806
1807
1808
1809
1810
1811
1812
1813
1814
1815
1816
1817
1818
1819
1820
1821
1822
1823
1824
1825
1826
1827
1828
1829
1830
1831
1832
1833
1834
1835
1836
1837
1838
1839
1840
1841
1842
1843
1844
1845
1846
1847
1848
1849
1850
1851
1852
1853
1854
1855
1856
1857
1858
1859
1860
1861
1862
1863
1864
1865
1866
1867
1868
1869
1870
1871
1872
1873
1874
1875
1876
1877
1878
1879
1880
1881
1882
1883
1884
1885
1886
1887
1888
1889
1890
1891
1892
1893
1894
1895
1896
1897
1898
1899
1900
1901
1902
1903
1904
1905
1906
1907
1908
1909
1910
1911
1912
1913
1914
1915
1916
1917
1918
1919
1920
1921
1922
1923
1924
1925
1926
1927
1928
1929
1930
1931
1932
1933
1934
1935
1936
1937
1938
1939
1940
1941
1942
1943
1944
1945
1946
1947
1948
1949
1950
1951
1952
1953
1954
1955
1956
1957
1958
1959
1960
1961
1962
1963
1964
1965
1966
1967
1968
1969
1970
1971
1972
1973
1974
1975
1976
1977
1978
1979
1980
1981
1982
1983
1984
1985
1986
1987
1988
1989
1990
1991
1992
1993
1994
1995
1996
1997
1998
1999
2000
2001
2002
2003
2004
2005
2006
2007
2008
2009
2010
2011
2012
2013
2014
2015
2016
2017
2018
2019
2020
2021
2022
2023
2024
2025
2026
2027
2028
2029
2030
2031
2032
2033
2034
2035
2036
2037
2038
2039
2040
2041
2042
2043
2044
2045
2046
2047
2048
2049
2050
2051
2052
2053
2054
2055
2056
2057
2058
2059
2060
2061
2062
2063
2064
2065
2066
2067
2068
2069
2070
2071
2072
2073
2074
2075
2076
2077
2078
2079
2080
2081
2082
2083
2084
2085
2086
2087
2088
2089
2090
2091
2092
2093
2094
2095
2096
2097
2098
2099
2100
2101
2102
2103
2104
2105
2106
2107
2108
2109
2110
2111
2112
2113
2114
2115
2116
2117
2118
2119
2120
2121
2122
2123
2124
2125
2126
2127
2128
2129
2130
2131
2132
2133
2134
2135
2136
2137
2138
2139
2140
2141
2142
2143
2144
2145
2146
2147
2148
2149
2150
2151
2152
2153
2154
2155
2156
2157
2158
2159
2160
2161
2162
2163
2164
2165
2166
2167
2168
2169
2170
2171
2172
2173
2174
2175
2176
2177
2178
2179
2180
2181
2182
2183
2184
2185
2186
2187
2188
2189
2190
2191
2192
2193
2194
2195
2196
2197
2198
2199
2200
|
<sect1 id="functions-datetime">
<title>Date/Time Functions and Operators</title>
<para>
<xref linkend="functions-datetime-table"/> shows the available
functions for date/time value processing, with details appearing in
the following subsections. <xref
linkend="operators-datetime-table"/> illustrates the behaviors of
the basic arithmetic operators (<literal>+</literal>,
<literal>*</literal>, etc.). For formatting functions, refer to
<xref linkend="functions-formatting"/>. You should be familiar with
the background information on date/time data types from <xref
linkend="datatype-datetime"/>.
</para>
<para>
In addition, the usual comparison operators shown in
<xref linkend="functions-comparison-op-table"/> are available for the
date/time types. Dates and timestamps (with or without time zone) are
all comparable, while times (with or without time zone) and intervals
can only be compared to other values of the same data type. When
comparing a timestamp without time zone to a timestamp with time zone,
the former value is assumed to be given in the time zone specified by
the <xref linkend="guc-timezone"/> configuration parameter, and is
rotated to UTC for comparison to the latter value (which is already
in UTC internally). Similarly, a date value is assumed to represent
midnight in the <varname>TimeZone</varname> zone when comparing it
to a timestamp.
</para>
<para>
All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
For brevity, these variants are not shown separately. Also, the
<literal>+</literal> and <literal>*</literal> operators come in commutative pairs (for
example both <type>date</type> <literal>+</literal> <type>integer</type>
and <type>integer</type> <literal>+</literal> <type>date</type>); we show
only one of each such pair.
</para>
<table id="operators-datetime-table">
<title>Date/Time Operators</title>
<tgroup cols="1">
<thead>
<row>
<entry role="func_table_entry"><para role="func_signature">
Operator
</para>
<para>
Description
</para>
<para>
Example(s)
</para></entry>
</row>
</thead>
<tbody>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>date</type> <literal>+</literal> <type>integer</type>
<returnvalue>date</returnvalue>
</para>
<para>
Add a number of days to a date
</para>
<para>
<literal>date '2001-09-28' + 7</literal>
<returnvalue>2001-10-05</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>date</type> <literal>+</literal> <type>interval</type>
<returnvalue>timestamp</returnvalue>
</para>
<para>
Add an interval to a date
</para>
<para>
<literal>date '2001-09-28' + interval '1 hour'</literal>
<returnvalue>2001-09-28 01:00:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>date</type> <literal>+</literal> <type>time</type>
<returnvalue>timestamp</returnvalue>
</para>
<para>
Add a time-of-day to a date
</para>
<para>
<literal>date '2001-09-28' + time '03:00'</literal>
<returnvalue>2001-09-28 03:00:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>interval</type> <literal>+</literal> <type>interval</type>
<returnvalue>interval</returnvalue>
</para>
<para>
Add intervals
</para>
<para>
<literal>interval '1 day' + interval '1 hour'</literal>
<returnvalue>1 day 01:00:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>timestamp</type> <literal>+</literal> <type>interval</type>
<returnvalue>timestamp</returnvalue>
</para>
<para>
Add an interval to a timestamp
</para>
<para>
<literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal>
<returnvalue>2001-09-29 00:00:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>time</type> <literal>+</literal> <type>interval</type>
<returnvalue>time</returnvalue>
</para>
<para>
Add an interval to a time
</para>
<para>
<literal>time '01:00' + interval '3 hours'</literal>
<returnvalue>04:00:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<literal>-</literal> <type>interval</type>
<returnvalue>interval</returnvalue>
</para>
<para>
Negate an interval
</para>
<para>
<literal>- interval '23 hours'</literal>
<returnvalue>-23:00:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>date</type> <literal>-</literal> <type>date</type>
<returnvalue>integer</returnvalue>
</para>
<para>
Subtract dates, producing the number of days elapsed
</para>
<para>
<literal>date '2001-10-01' - date '2001-09-28'</literal>
<returnvalue>3</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>date</type> <literal>-</literal> <type>integer</type>
<returnvalue>date</returnvalue>
</para>
<para>
Subtract a number of days from a date
</para>
<para>
<literal>date '2001-10-01' - 7</literal>
<returnvalue>2001-09-24</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>date</type> <literal>-</literal> <type>interval</type>
<returnvalue>timestamp</returnvalue>
</para>
<para>
Subtract an interval from a date
</para>
<para>
<literal>date '2001-09-28' - interval '1 hour'</literal>
<returnvalue>2001-09-27 23:00:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>time</type> <literal>-</literal> <type>time</type>
<returnvalue>interval</returnvalue>
</para>
<para>
Subtract times
</para>
<para>
<literal>time '05:00' - time '03:00'</literal>
<returnvalue>02:00:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>time</type> <literal>-</literal> <type>interval</type>
<returnvalue>time</returnvalue>
</para>
<para>
Subtract an interval from a time
</para>
<para>
<literal>time '05:00' - interval '2 hours'</literal>
<returnvalue>03:00:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>timestamp</type> <literal>-</literal> <type>interval</type>
<returnvalue>timestamp</returnvalue>
</para>
<para>
Subtract an interval from a timestamp
</para>
<para>
<literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal>
<returnvalue>2001-09-28 00:00:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>interval</type> <literal>-</literal> <type>interval</type>
<returnvalue>interval</returnvalue>
</para>
<para>
Subtract intervals
</para>
<para>
<literal>interval '1 day' - interval '1 hour'</literal>
<returnvalue>1 day -01:00:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>timestamp</type> <literal>-</literal> <type>timestamp</type>
<returnvalue>interval</returnvalue>
</para>
<para>
Subtract timestamps (converting 24-hour intervals into days,
similarly to <link
linkend="function-justify-hours"><function>justify_hours()</function></link>)
</para>
<para>
<literal>timestamp '2001-09-29 03:00' - timestamp '2001-07-27 12:00'</literal>
<returnvalue>63 days 15:00:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>interval</type> <literal>*</literal> <type>double precision</type>
<returnvalue>interval</returnvalue>
</para>
<para>
Multiply an interval by a scalar
</para>
<para>
<literal>interval '1 second' * 900</literal>
<returnvalue>00:15:00</returnvalue>
</para>
<para>
<literal>interval '1 day' * 21</literal>
<returnvalue>21 days</returnvalue>
</para>
<para>
<literal>interval '1 hour' * 3.5</literal>
<returnvalue>03:30:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>interval</type> <literal>/</literal> <type>double precision</type>
<returnvalue>interval</returnvalue>
</para>
<para>
Divide an interval by a scalar
</para>
<para>
<literal>interval '1 hour' / 1.5</literal>
<returnvalue>00:40:00</returnvalue>
</para></entry>
</row>
</tbody>
</tgroup>
</table>
<table id="functions-datetime-table">
<title>Date/Time Functions</title>
<tgroup cols="1">
<thead>
<row>
<entry role="func_table_entry"><para role="func_signature">
Function
</para>
<para>
Description
</para>
<para>
Example(s)
</para></entry>
</row>
</thead>
<tbody>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>age</primary>
</indexterm>
<function>age</function> ( <type>timestamp</type>, <type>timestamp</type> )
<returnvalue>interval</returnvalue>
</para>
<para>
Subtract arguments, producing a <quote>symbolic</quote> result that
uses years and months, rather than just days
</para>
<para>
<literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal>
<returnvalue>43 years 9 mons 27 days</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<function>age</function> ( <type>timestamp</type> )
<returnvalue>interval</returnvalue>
</para>
<para>
Subtract argument from <function>current_date</function> (at midnight)
</para>
<para>
<literal>age(timestamp '1957-06-13')</literal>
<returnvalue>62 years 6 mons 10 days</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>clock_timestamp</primary>
</indexterm>
<function>clock_timestamp</function> ( )
<returnvalue>timestamp with time zone</returnvalue>
</para>
<para>
Current date and time (changes during statement execution);
see <xref linkend="functions-datetime-current"/>
</para>
<para>
<literal>clock_timestamp()</literal>
<returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>current_date</primary>
</indexterm>
<function>current_date</function>
<returnvalue>date</returnvalue>
</para>
<para>
Current date; see <xref linkend="functions-datetime-current"/>
</para>
<para>
<literal>current_date</literal>
<returnvalue>2019-12-23</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>current_time</primary>
</indexterm>
<function>current_time</function>
<returnvalue>time with time zone</returnvalue>
</para>
<para>
Current time of day; see <xref linkend="functions-datetime-current"/>
</para>
<para>
<literal>current_time</literal>
<returnvalue>14:39:53.662522-05</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<function>current_time</function> ( <type>integer</type> )
<returnvalue>time with time zone</returnvalue>
</para>
<para>
Current time of day, with limited precision;
see <xref linkend="functions-datetime-current"/>
</para>
<para>
<literal>current_time(2)</literal>
<returnvalue>14:39:53.66-05</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>current_timestamp</primary>
</indexterm>
<function>current_timestamp</function>
<returnvalue>timestamp with time zone</returnvalue>
</para>
<para>
Current date and time (start of current transaction);
see <xref linkend="functions-datetime-current"/>
</para>
<para>
<literal>current_timestamp</literal>
<returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<function>current_timestamp</function> ( <type>integer</type> )
<returnvalue>timestamp with time zone</returnvalue>
</para>
<para>
Current date and time (start of current transaction), with limited precision;
see <xref linkend="functions-datetime-current"/>
</para>
<para>
<literal>current_timestamp(0)</literal>
<returnvalue>2019-12-23 14:39:53-05</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>date_add</primary>
</indexterm>
<function>date_add</function> ( <type>timestamp with time zone</type>, <type>interval</type> <optional>, <type>text</type> </optional> )
<returnvalue>timestamp with time zone</returnvalue>
</para>
<para>
Add an <type>interval</type> to a <type>timestamp with time
zone</type>, computing times of day and daylight-savings adjustments
according to the time zone named by the third argument, or the
current <xref linkend="guc-timezone"/> setting if that is omitted.
The form with two arguments is equivalent to the <type>timestamp with
time zone</type> <literal>+</literal> <type>interval</type> operator.
</para>
<para>
<literal>date_add('2021-10-31 00:00:00+02'::timestamptz, '1 day'::interval, 'Europe/Warsaw')</literal>
<returnvalue>2021-10-31 23:00:00+00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<function>date_bin</function> ( <type>interval</type>, <type>timestamp</type>, <type>timestamp</type> )
<returnvalue>timestamp</returnvalue>
</para>
<para>
Bin input into specified interval aligned with specified origin; see <xref linkend="functions-datetime-bin"/>
</para>
<para>
<literal>date_bin('15 minutes', timestamp '2001-02-16 20:38:40', timestamp '2001-02-16 20:05:00')</literal>
<returnvalue>2001-02-16 20:35:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>date_part</primary>
</indexterm>
<function>date_part</function> ( <type>text</type>, <type>timestamp</type> )
<returnvalue>double precision</returnvalue>
</para>
<para>
Get timestamp subfield (equivalent to <function>extract</function>);
see <xref linkend="functions-datetime-extract"/>
</para>
<para>
<literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal>
<returnvalue>20</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<function>date_part</function> ( <type>text</type>, <type>interval</type> )
<returnvalue>double precision</returnvalue>
</para>
<para>
Get interval subfield (equivalent to <function>extract</function>);
see <xref linkend="functions-datetime-extract"/>
</para>
<para>
<literal>date_part('month', interval '2 years 3 months')</literal>
<returnvalue>3</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>date_subtract</primary>
</indexterm>
<function>date_subtract</function> ( <type>timestamp with time zone</type>, <type>interval</type> <optional>, <type>text</type> </optional> )
<returnvalue>timestamp with time zone</returnvalue>
</para>
<para>
Subtract an <type>interval</type> from a <type>timestamp with time
zone</type>, computing times of day and daylight-savings adjustments
according to the time zone named by the third argument, or the
current <xref linkend="guc-timezone"/> setting if that is omitted.
The form with two arguments is equivalent to the <type>timestamp with
time zone</type> <literal>-</literal> <type>interval</type> operator.
</para>
<para>
<literal>date_subtract('2021-11-01 00:00:00+01'::timestamptz, '1 day'::interval, 'Europe/Warsaw')</literal>
<returnvalue>2021-10-30 22:00:00+00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>date_trunc</primary>
</indexterm>
<function>date_trunc</function> ( <type>text</type>, <type>timestamp</type> )
<returnvalue>timestamp</returnvalue>
</para>
<para>
Truncate to specified precision; see <xref linkend="functions-datetime-trunc"/>
</para>
<para>
<literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal>
<returnvalue>2001-02-16 20:00:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<function>date_trunc</function> ( <type>text</type>, <type>timestamp with time zone</type>, <type>text</type> )
<returnvalue>timestamp with time zone</returnvalue>
</para>
<para>
Truncate to specified precision in the specified time zone; see
<xref linkend="functions-datetime-trunc"/>
</para>
<para>
<literal>date_trunc('day', timestamptz '2001-02-16 20:38:40+00', 'Australia/Sydney')</literal>
<returnvalue>2001-02-16 13:00:00+00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<function>date_trunc</function> ( <type>text</type>, <type>interval</type> )
<returnvalue>interval</returnvalue>
</para>
<para>
Truncate to specified precision; see
<xref linkend="functions-datetime-trunc"/>
</para>
<para>
<literal>date_trunc('hour', interval '2 days 3 hours 40 minutes')</literal>
<returnvalue>2 days 03:00:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>extract</primary>
</indexterm>
<function>extract</function> ( <parameter>field</parameter> <literal>from</literal> <type>timestamp</type> )
<returnvalue>numeric</returnvalue>
</para>
<para>
Get timestamp subfield; see <xref linkend="functions-datetime-extract"/>
</para>
<para>
<literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal>
<returnvalue>20</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<function>extract</function> ( <parameter>field</parameter> <literal>from</literal> <type>interval</type> )
<returnvalue>numeric</returnvalue>
</para>
<para>
Get interval subfield; see <xref linkend="functions-datetime-extract"/>
</para>
<para>
<literal>extract(month from interval '2 years 3 months')</literal>
<returnvalue>3</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>isfinite</primary>
</indexterm>
<function>isfinite</function> ( <type>date</type> )
<returnvalue>boolean</returnvalue>
</para>
<para>
Test for finite date (not +/-infinity)
</para>
<para>
<literal>isfinite(date '2001-02-16')</literal>
<returnvalue>true</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<function>isfinite</function> ( <type>timestamp</type> )
<returnvalue>boolean</returnvalue>
</para>
<para>
Test for finite timestamp (not +/-infinity)
</para>
<para>
<literal>isfinite(timestamp 'infinity')</literal>
<returnvalue>false</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<function>isfinite</function> ( <type>interval</type> )
<returnvalue>boolean</returnvalue>
</para>
<para>
Test for finite interval (not +/-infinity)
</para>
<para>
<literal>isfinite(interval '4 hours')</literal>
<returnvalue>true</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm id="function-justify-days">
<primary>justify_days</primary>
</indexterm>
<function>justify_days</function> ( <type>interval</type> )
<returnvalue>interval</returnvalue>
</para>
<para>
Adjust interval, converting 30-day time periods to months
</para>
<para>
<literal>justify_days(interval '1 year 65 days')</literal>
<returnvalue>1 year 2 mons 5 days</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm id="function-justify-hours">
<primary>justify_hours</primary>
</indexterm>
<function>justify_hours</function> ( <type>interval</type> )
<returnvalue>interval</returnvalue>
</para>
<para>
Adjust interval, converting 24-hour time periods to days
</para>
<para>
<literal>justify_hours(interval '50 hours 10 minutes')</literal>
<returnvalue>2 days 02:10:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>justify_interval</primary>
</indexterm>
<function>justify_interval</function> ( <type>interval</type> )
<returnvalue>interval</returnvalue>
</para>
<para>
Adjust interval using <function>justify_days</function>
and <function>justify_hours</function>, with additional sign
adjustments
</para>
<para>
<literal>justify_interval(interval '1 mon -1 hour')</literal>
<returnvalue>29 days 23:00:00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>localtime</primary>
</indexterm>
<function>localtime</function>
<returnvalue>time</returnvalue>
</para>
<para>
Current time of day;
see <xref linkend="functions-datetime-current"/>
</para>
<para>
<literal>localtime</literal>
<returnvalue>14:39:53.662522</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<function>localtime</function> ( <type>integer</type> )
<returnvalue>time</returnvalue>
</para>
<para>
Current time of day, with limited precision;
see <xref linkend="functions-datetime-current"/>
</para>
<para>
<literal>localtime(0)</literal>
<returnvalue>14:39:53</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>localtimestamp</primary>
</indexterm>
<function>localtimestamp</function>
<returnvalue>timestamp</returnvalue>
</para>
<para>
Current date and time (start of current transaction);
see <xref linkend="functions-datetime-current"/>
</para>
<para>
<literal>localtimestamp</literal>
<returnvalue>2019-12-23 14:39:53.662522</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<function>localtimestamp</function> ( <type>integer</type> )
<returnvalue>timestamp</returnvalue>
</para>
<para>
Current date and time (start of current
transaction), with limited precision;
see <xref linkend="functions-datetime-current"/>
</para>
<para>
<literal>localtimestamp(2)</literal>
<returnvalue>2019-12-23 14:39:53.66</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>make_date</primary>
</indexterm>
<function>make_date</function> ( <parameter>year</parameter> <type>int</type>,
<parameter>month</parameter> <type>int</type>,
<parameter>day</parameter> <type>int</type> )
<returnvalue>date</returnvalue>
</para>
<para>
Create date from year, month and day fields
(negative years signify BC)
</para>
<para>
<literal>make_date(2013, 7, 15)</literal>
<returnvalue>2013-07-15</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature"><indexterm>
<primary>make_interval</primary>
</indexterm>
<function>make_interval</function> ( <optional> <parameter>years</parameter> <type>int</type>
<optional>, <parameter>months</parameter> <type>int</type>
<optional>, <parameter>weeks</parameter> <type>int</type>
<optional>, <parameter>days</parameter> <type>int</type>
<optional>, <parameter>hours</parameter> <type>int</type>
<optional>, <parameter>mins</parameter> <type>int</type>
<optional>, <parameter>secs</parameter> <type>double precision</type>
</optional></optional></optional></optional></optional></optional></optional> )
<returnvalue>interval</returnvalue>
</para>
<para>
Create interval from years, months, weeks, days, hours, minutes and
seconds fields, each of which can default to zero
</para>
<para>
<literal>make_interval(days => 10)</literal>
<returnvalue>10 days</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>make_time</primary>
</indexterm>
<function>make_time</function> ( <parameter>hour</parameter> <type>int</type>,
<parameter>min</parameter> <type>int</type>,
<parameter>sec</parameter> <type>double precision</type> )
<returnvalue>time</returnvalue>
</para>
<para>
Create time from hour, minute and seconds fields
</para>
<para>
<literal>make_time(8, 15, 23.5)</literal>
<returnvalue>08:15:23.5</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>make_timestamp</primary>
</indexterm>
<function>make_timestamp</function> ( <parameter>year</parameter> <type>int</type>,
<parameter>month</parameter> <type>int</type>,
<parameter>day</parameter> <type>int</type>,
<parameter>hour</parameter> <type>int</type>,
<parameter>min</parameter> <type>int</type>,
<parameter>sec</parameter> <type>double precision</type> )
<returnvalue>timestamp</returnvalue>
</para>
<para>
Create timestamp from year, month, day, hour, minute and seconds fields
(negative years signify BC)
</para>
<para>
<literal>make_timestamp(2013, 7, 15, 8, 15, 23.5)</literal>
<returnvalue>2013-07-15 08:15:23.5</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>make_timestamptz</primary>
</indexterm>
<function>make_timestamptz</function> ( <parameter>year</parameter> <type>int</type>,
<parameter>month</parameter> <type>int</type>,
<parameter>day</parameter> <type>int</type>,
<parameter>hour</parameter> <type>int</type>,
<parameter>min</parameter> <type>int</type>,
<parameter>sec</parameter> <type>double precision</type>
<optional>, <parameter>timezone</parameter> <type>text</type> </optional> )
<returnvalue>timestamp with time zone</returnvalue>
</para>
<para>
Create timestamp with time zone from year, month, day, hour, minute
and seconds fields (negative years signify BC).
If <parameter>timezone</parameter> is not
specified, the current time zone is used; the examples assume the
session time zone is <literal>Europe/London</literal>
</para>
<para>
<literal>make_timestamptz(2013, 7, 15, 8, 15, 23.5)</literal>
<returnvalue>2013-07-15 08:15:23.5+01</returnvalue>
</para>
<para>
<literal>make_timestamptz(2013, 7, 15, 8, 15, 23.5, 'America/New_York')</literal>
<returnvalue>2013-07-15 13:15:23.5+01</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>now</primary>
</indexterm>
<function>now</function> ( )
<returnvalue>timestamp with time zone</returnvalue>
</para>
<para>
Current date and time (start of current transaction);
see <xref linkend="functions-datetime-current"/>
</para>
<para>
<literal>now()</literal>
<returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>statement_timestamp</primary>
</indexterm>
<function>statement_timestamp</function> ( )
<returnvalue>timestamp with time zone</returnvalue>
</para>
<para>
Current date and time (start of current statement);
see <xref linkend="functions-datetime-current"/>
</para>
<para>
<literal>statement_timestamp()</literal>
<returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>timeofday</primary>
</indexterm>
<function>timeofday</function> ( )
<returnvalue>text</returnvalue>
</para>
<para>
Current date and time
(like <function>clock_timestamp</function>, but as a <type>text</type> string);
see <xref linkend="functions-datetime-current"/>
</para>
<para>
<literal>timeofday()</literal>
<returnvalue>Mon Dec 23 14:39:53.662522 2019 EST</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>transaction_timestamp</primary>
</indexterm>
<function>transaction_timestamp</function> ( )
<returnvalue>timestamp with time zone</returnvalue>
</para>
<para>
Current date and time (start of current transaction);
see <xref linkend="functions-datetime-current"/>
</para>
<para>
<literal>transaction_timestamp()</literal>
<returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>to_timestamp</primary>
</indexterm>
<function>to_timestamp</function> ( <type>double precision</type> )
<returnvalue>timestamp with time zone</returnvalue>
</para>
<para>
Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to
timestamp with time zone
</para>
<para>
<literal>to_timestamp(1284352323)</literal>
<returnvalue>2010-09-13 04:32:03+00</returnvalue>
</para></entry>
</row>
</tbody>
</tgroup>
</table>
<para>
<indexterm>
<primary>OVERLAPS</primary>
</indexterm>
In addition to these functions, the SQL <literal>OVERLAPS</literal> operator is
supported:
<synopsis>
(<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
(<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
</synopsis>
This expression yields true when two time periods (defined by their
endpoints) overlap, false when they do not overlap. The endpoints
can be specified as pairs of dates, times, or time stamps; or as
a date, time, or time stamp followed by an interval. When a pair
of values is provided, either the start or the end can be written
first; <literal>OVERLAPS</literal> automatically takes the earlier value
of the pair as the start. Each time period is considered to
represent the half-open interval <replaceable>start</replaceable> <literal><=</literal>
<replaceable>time</replaceable> <literal><</literal> <replaceable>end</replaceable>, unless
<replaceable>start</replaceable> and <replaceable>end</replaceable> are equal in which case it
represents that single time instant. This means for instance that two
time periods with only an endpoint in common do not overlap.
</para>
<screen>
SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
(DATE '2001-10-30', DATE '2002-10-30');
<lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
(DATE '2001-10-30', DATE '2002-10-30');
<lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
SELECT (DATE '2001-10-29', DATE '2001-10-30') OVERLAPS
(DATE '2001-10-30', DATE '2001-10-31');
<lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
SELECT (DATE '2001-10-30', DATE '2001-10-30') OVERLAPS
(DATE '2001-10-30', DATE '2001-10-31');
<lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
</screen>
<para>
When adding an <type>interval</type> value to (or subtracting an
<type>interval</type> value from) a <type>timestamp</type>
or <type>timestamp with time zone</type> value, the months, days, and
microseconds fields of the <type>interval</type> value are handled in turn.
First, a nonzero months field advances or decrements the date of the
timestamp by the indicated number of months, keeping the day of month the
same unless it would be past the end of the new month, in which case the
last day of that month is used. (For example, March 31 plus 1 month
becomes April 30, but March 31 plus 2 months becomes May 31.)
Then the days field advances or decrements the date of the timestamp by
the indicated number of days. In both these steps the local time of day
is kept the same. Finally, if there is a nonzero microseconds field, it
is added or subtracted literally.
When doing arithmetic on a <type>timestamp with time zone</type> value in
a time zone that recognizes DST, this means that adding or subtracting
(say) <literal>interval '1 day'</literal> does not necessarily have the
same result as adding or subtracting <literal>interval '24
hours'</literal>.
For example, with the session time zone set
to <literal>America/Denver</literal>:
<screen>
SELECT timestamp with time zone '2005-04-02 12:00:00-07' + interval '1 day';
<lineannotation>Result: </lineannotation><computeroutput>2005-04-03 12:00:00-06</computeroutput>
SELECT timestamp with time zone '2005-04-02 12:00:00-07' + interval '24 hours';
<lineannotation>Result: </lineannotation><computeroutput>2005-04-03 13:00:00-06</computeroutput>
</screen>
This happens because an hour was skipped due to a change in daylight saving
time at <literal>2005-04-03 02:00:00</literal> in time zone
<literal>America/Denver</literal>.
</para>
<para>
Note there can be ambiguity in the <literal>months</literal> field returned by
<function>age</function> because different months have different numbers of
days. <productname>PostgreSQL</productname>'s approach uses the month from the
earlier of the two dates when calculating partial months. For example,
<literal>age('2004-06-01', '2004-04-30')</literal> uses April to yield
<literal>1 mon 1 day</literal>, while using May would yield <literal>1 mon 2
days</literal> because May has 31 days, while April has only 30.
</para>
<para>
Subtraction of dates and timestamps can also be complex. One conceptually
simple way to perform subtraction is to convert each value to a number
of seconds using <literal>EXTRACT(EPOCH FROM ...)</literal>, then subtract the
results; this produces the
number of <emphasis>seconds</emphasis> between the two values. This will adjust
for the number of days in each month, timezone changes, and daylight
saving time adjustments. Subtraction of date or timestamp
values with the <quote><literal>-</literal></quote> operator
returns the number of days (24-hours) and hours/minutes/seconds
between the values, making the same adjustments. The <function>age</function>
function returns years, months, days, and hours/minutes/seconds,
performing field-by-field subtraction and then adjusting for negative
field values. The following queries illustrate the differences in these
approaches. The sample results were produced with <literal>timezone
= 'US/Eastern'</literal>; there is a daylight saving time change between the
two dates used:
</para>
<screen>
SELECT EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00');
<lineannotation>Result: </lineannotation><computeroutput>10537200.000000</computeroutput>
SELECT (EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00'))
/ 60 / 60 / 24;
<lineannotation>Result: </lineannotation><computeroutput>121.9583333333333333</computeroutput>
SELECT timestamptz '2013-07-01 12:00:00' - timestamptz '2013-03-01 12:00:00';
<lineannotation>Result: </lineannotation><computeroutput>121 days 23:00:00</computeroutput>
SELECT age(timestamptz '2013-07-01 12:00:00', timestamptz '2013-03-01 12:00:00');
<lineannotation>Result: </lineannotation><computeroutput>4 mons</computeroutput>
</screen>
<sect2 id="functions-datetime-extract">
<title><function>EXTRACT</function>, <function>date_part</function></title>
<indexterm>
<primary>date_part</primary>
</indexterm>
<indexterm>
<primary>extract</primary>
</indexterm>
<synopsis>
EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
</synopsis>
<para>
The <function>extract</function> function retrieves subfields
such as year or hour from date/time values.
<replaceable>source</replaceable> must be a value expression of
type <type>timestamp</type>, <type>date</type>, <type>time</type>,
or <type>interval</type>. (Timestamps and times can be with or
without time zone.)
<replaceable>field</replaceable> is an identifier or
string that selects what field to extract from the source value.
Not all fields are valid for every input data type; for example, fields
smaller than a day cannot be extracted from a <type>date</type>, while
fields of a day or more cannot be extracted from a <type>time</type>.
The <function>extract</function> function returns values of type
<type>numeric</type>.
</para>
<para>
The following are valid field names:
<!-- alphabetical -->
<variablelist>
<varlistentry>
<term><literal>century</literal></term>
<listitem>
<para>
The century; for <type>interval</type> values, the year field
divided by 100
</para>
<screen>
SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
<lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
SELECT EXTRACT(CENTURY FROM DATE '0001-01-01 AD');
<lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
SELECT EXTRACT(CENTURY FROM DATE '0001-12-31 BC');
<lineannotation>Result: </lineannotation><computeroutput>-1</computeroutput>
SELECT EXTRACT(CENTURY FROM INTERVAL '2001 years');
<lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
</screen>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>day</literal></term>
<listitem>
<para>
The day of the month (1–31); for <type>interval</type>
values, the number of days
</para>
<screen>
SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
SELECT EXTRACT(DAY FROM INTERVAL '40 days 1 minute');
<lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
</screen>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>decade</literal></term>
<listitem>
<para>
The year field divided by 10
</para>
<screen>
SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
</screen>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>dow</literal></term>
<listitem>
<para>
The day of the week as Sunday (<literal>0</literal>) to
Saturday (<literal>6</literal>)
</para>
<screen>
SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
</screen>
<para>
Note that <function>extract</function>'s day of the week numbering
differs from that of the <function>to_char(...,
'D')</function> function.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>doy</literal></term>
<listitem>
<para>
The day of the year (1–365/366)
</para>
<screen>
SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
</screen>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>epoch</literal></term>
<listitem>
<para>
For <type>timestamp with time zone</type> values, the
number of seconds since 1970-01-01 00:00:00 UTC (negative for
timestamps before that);
for <type>date</type> and <type>timestamp</type> values, the
nominal number of seconds since 1970-01-01 00:00:00,
without regard to timezone or daylight-savings rules;
for <type>interval</type> values, the total number
of seconds in the interval
</para>
<screen>
SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08');
<lineannotation>Result: </lineannotation><computeroutput>982384720.120000</computeroutput>
SELECT EXTRACT(EPOCH FROM TIMESTAMP '2001-02-16 20:38:40.12');
<lineannotation>Result: </lineannotation><computeroutput>982355920.120000</computeroutput>
SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
<lineannotation>Result: </lineannotation><computeroutput>442800.000000</computeroutput>
</screen>
<para>
You can convert an epoch value back to a <type>timestamp with time zone</type>
with <function>to_timestamp</function>:
</para>
<screen>
SELECT to_timestamp(982384720.12);
<lineannotation>Result: </lineannotation><computeroutput>2001-02-17 04:38:40.12+00</computeroutput>
</screen>
<para>
Beware that applying <function>to_timestamp</function> to an epoch
extracted from a <type>date</type> or <type>timestamp</type> value
could produce a misleading result: the result will effectively
assume that the original value had been given in UTC, which might
not be the case.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>hour</literal></term>
<listitem>
<para>
The hour field (0–23 in timestamps, unrestricted in
intervals)
</para>
<screen>
SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
</screen>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>isodow</literal></term>
<listitem>
<para>
The day of the week as Monday (<literal>1</literal>) to
Sunday (<literal>7</literal>)
</para>
<screen>
SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
</screen>
<para>
This is identical to <literal>dow</literal> except for Sunday. This
matches the <acronym>ISO</acronym> 8601 day of the week numbering.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>isoyear</literal></term>
<listitem>
<para>
The <acronym>ISO</acronym> 8601 week-numbering year that the date
falls in
</para>
<screen>
SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
<lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
<lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
</screen>
<para>
Each <acronym>ISO</acronym> 8601 week-numbering year begins with the
Monday of the week containing the 4th of January, so in early
January or late December the <acronym>ISO</acronym> year may be
different from the Gregorian year. See the <literal>week</literal>
field for more information.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>julian</literal></term>
<listitem>
<para>
The <firstterm>Julian Date</firstterm> corresponding to the
date or timestamp. Timestamps
that are not local midnight result in a fractional value. See
<xref linkend="datetime-julian-dates"/> for more information.
</para>
<screen>
SELECT EXTRACT(JULIAN FROM DATE '2006-01-01');
<lineannotation>Result: </lineannotation><computeroutput>2453737</computeroutput>
SELECT EXTRACT(JULIAN FROM TIMESTAMP '2006-01-01 12:00');
<lineannotation>Result: </lineannotation><computeroutput>2453737.50000000000000000000</computeroutput>
</screen>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>microseconds</literal></term>
<listitem>
<para>
The seconds field, including fractional parts, multiplied by 1
000 000; note that this includes full seconds
</para>
<screen>
SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
<lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
</screen>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>millennium</literal></term>
<listitem>
<para>
The millennium; for <type>interval</type> values, the year field
divided by 1000
</para>
<screen>
SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
SELECT EXTRACT(MILLENNIUM FROM INTERVAL '2001 years');
<lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
</screen>
<para>
Years in the 1900s are in the second millennium.
The third millennium started January 1, 2001.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>milliseconds</literal></term>
<listitem>
<para>
The seconds field, including fractional parts, multiplied by
1000. Note that this includes full seconds.
</para>
<screen>
SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
<lineannotation>Result: </lineannotation><computeroutput>28500.000</computeroutput>
</screen>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>minute</literal></term>
<listitem>
<para>
The minutes field (0–59)
</para>
<screen>
SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
</screen>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>month</literal></term>
<listitem>
<para>
The number of the month within the year (1–12);
for <type>interval</type> values, the number of months modulo 12
(0–11)
</para>
<screen>
SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
<lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
<lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
</screen>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>quarter</literal></term>
<listitem>
<para>
The quarter of the year (1–4) that the date is in;
for <type>interval</type> values, the month field divided by 3
plus 1
</para>
<screen>
SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
SELECT EXTRACT(QUARTER FROM INTERVAL '1 year 6 months');
<lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
</screen>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>second</literal></term>
<listitem>
<para>
The seconds field, including any fractional seconds
</para>
<screen>
SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>40.000000</computeroutput>
SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
<lineannotation>Result: </lineannotation><computeroutput>28.500000</computeroutput>
</screen>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>timezone</literal></term>
<listitem>
<para>
The time zone offset from UTC, measured in seconds. Positive values
correspond to time zones east of UTC, negative values to
zones west of UTC. (Technically,
<productname>PostgreSQL</productname> does not use UTC because
leap seconds are not handled.)
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>timezone_hour</literal></term>
<listitem>
<para>
The hour component of the time zone offset
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>timezone_minute</literal></term>
<listitem>
<para>
The minute component of the time zone offset
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>week</literal></term>
<listitem>
<para>
The number of the <acronym>ISO</acronym> 8601 week-numbering week of
the year. By definition, ISO weeks start on Mondays and the first
week of a year contains January 4 of that year. In other words, the
first Thursday of a year is in week 1 of that year.
</para>
<para>
In the ISO week-numbering system, it is possible for early-January
dates to be part of the 52nd or 53rd week of the previous year, and for
late-December dates to be part of the first week of the next year.
For example, <literal>2005-01-01</literal> is part of the 53rd week of year
2004, and <literal>2006-01-01</literal> is part of the 52nd week of year
2005, while <literal>2012-12-31</literal> is part of the first week of 2013.
It's recommended to use the <literal>isoyear</literal> field together with
<literal>week</literal> to get consistent results.
</para>
<para>
For <type>interval</type> values, the week field is simply the number
of integral days divided by 7.
</para>
<screen>
SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
SELECT EXTRACT(WEEK FROM INTERVAL '13 days 24 hours');
<lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
</screen>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>year</literal></term>
<listitem>
<para>
The year field. Keep in mind there is no <literal>0 AD</literal>, so subtracting
<literal>BC</literal> years from <literal>AD</literal> years should be done with care.
</para>
<screen>
SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
</screen>
</listitem>
</varlistentry>
</variablelist>
</para>
<para>
When processing an <type>interval</type> value,
the <function>extract</function> function produces field values that
match the interpretation used by the interval output function. This
can produce surprising results if one starts with a non-normalized
interval representation, for example:
<screen>
SELECT INTERVAL '80 minutes';
<lineannotation>Result: </lineannotation><computeroutput>01:20:00</computeroutput>
SELECT EXTRACT(MINUTES FROM INTERVAL '80 minutes');
<lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
</screen>
</para>
<note>
<para>
When the input value is +/-Infinity, <function>extract</function> returns
+/-Infinity for monotonically-increasing fields (<literal>epoch</literal>,
<literal>julian</literal>, <literal>year</literal>, <literal>isoyear</literal>,
<literal>decade</literal>, <literal>century</literal>, and <literal>millennium</literal>
for <type>timestamp</type> inputs; <literal>epoch</literal>, <literal>hour</literal>,
<literal>day</literal>, <literal>year</literal>, <literal>decade</literal>,
<literal>century</literal>, and <literal>millennium</literal> for
<type>interval</type> inputs).
For other fields, NULL is returned. <productname>PostgreSQL</productname>
versions before 9.6 returned zero for all cases of infinite input.
</para>
</note>
<para>
The <function>extract</function> function is primarily intended
for computational processing. For formatting date/time values for
display, see <xref linkend="functions-formatting"/>.
</para>
<para>
The <function>date_part</function> function is modeled on the traditional
<productname>Ingres</productname> equivalent to the
<acronym>SQL</acronym>-standard function <function>extract</function>:
<synopsis>
date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
</synopsis>
Note that here the <replaceable>field</replaceable> parameter needs to
be a string value, not a name. The valid field names for
<function>date_part</function> are the same as for
<function>extract</function>.
For historical reasons, the <function>date_part</function> function
returns values of type <type>double precision</type>. This can result in
a loss of precision in certain uses. Using <function>extract</function>
is recommended instead.
</para>
<screen>
SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
<lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
</screen>
</sect2>
<sect2 id="functions-datetime-trunc">
<title><function>date_trunc</function></title>
<indexterm>
<primary>date_trunc</primary>
</indexterm>
<para>
The function <function>date_trunc</function> is conceptually
similar to the <function>trunc</function> function for numbers.
</para>
<para>
<synopsis>
date_trunc(<replaceable>field</replaceable>, <replaceable>source</replaceable> <optional>, <replaceable>time_zone</replaceable> </optional>)
</synopsis>
<replaceable>source</replaceable> is a value expression of type
<type>timestamp</type>, <type>timestamp with time zone</type>,
or <type>interval</type>.
(Values of type <type>date</type> and
<type>time</type> are cast automatically to <type>timestamp</type> or
<type>interval</type>, respectively.)
<replaceable>field</replaceable> selects to which precision to
truncate the input value. The return value is likewise of type
<type>timestamp</type>, <type>timestamp with time zone</type>,
or <type>interval</type>,
and it has all fields that are less significant than the
selected one set to zero (or one, for day and month).
</para>
<para>
Valid values for <replaceable>field</replaceable> are:
<simplelist>
<member><literal>microseconds</literal></member>
<member><literal>milliseconds</literal></member>
<member><literal>second</literal></member>
<member><literal>minute</literal></member>
<member><literal>hour</literal></member>
<member><literal>day</literal></member>
<member><literal>week</literal></member>
<member><literal>month</literal></member>
<member><literal>quarter</literal></member>
<member><literal>year</literal></member>
<member><literal>decade</literal></member>
<member><literal>century</literal></member>
<member><literal>millennium</literal></member>
</simplelist>
</para>
<para>
When the input value is of type <type>timestamp with time zone</type>,
the truncation is performed with respect to a particular time zone;
for example, truncation to <literal>day</literal> produces a value that
is midnight in that zone. By default, truncation is done with respect
to the current <xref linkend="guc-timezone"/> setting, but the
optional <replaceable>time_zone</replaceable> argument can be provided
to specify a different time zone. The time zone name can be specified
in any of the ways described in <xref linkend="datatype-timezones"/>.
</para>
<para>
A time zone cannot be specified when processing <type>timestamp without
time zone</type> or <type>interval</type> inputs. These are always
taken at face value.
</para>
<para>
Examples (assuming the local time zone is <literal>America/New_York</literal>):
<screen>
SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00');
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 00:00:00-05</computeroutput>
SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00', 'Australia/Sydney');
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 08:00:00-05</computeroutput>
SELECT date_trunc('hour', INTERVAL '3 days 02:47:33');
<lineannotation>Result: </lineannotation><computeroutput>3 days 02:00:00</computeroutput>
</screen>
</para>
</sect2>
<sect2 id="functions-datetime-bin">
<title><function>date_bin</function></title>
<indexterm>
<primary>date_bin</primary>
</indexterm>
<para>
The function <function>date_bin</function> <quote>bins</quote> the input
timestamp into the specified interval (the <firstterm>stride</firstterm>)
aligned with a specified origin.
</para>
<para>
<synopsis>
date_bin(<replaceable>stride</replaceable>, <replaceable>source</replaceable>, <replaceable>origin</replaceable>)
</synopsis>
<replaceable>source</replaceable> is a value expression of type
<type>timestamp</type> or <type>timestamp with time zone</type>. (Values
of type <type>date</type> are cast automatically to
<type>timestamp</type>.) <replaceable>stride</replaceable> is a value
expression of type <type>interval</type>. The return value is likewise
of type <type>timestamp</type> or <type>timestamp with time zone</type>,
and it marks the beginning of the bin into which the
<replaceable>source</replaceable> is placed.
</para>
<para>
Examples:
<screen>
SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-01-01');
<lineannotation>Result: </lineannotation><computeroutput>2020-02-11 15:30:00</computeroutput>
SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-01-01 00:02:30');
<lineannotation>Result: </lineannotation><computeroutput>2020-02-11 15:32:30</computeroutput>
</screen>
</para>
<para>
In the case of full units (1 minute, 1 hour, etc.), it gives the same result as
the analogous <function>date_trunc</function> call, but the difference is
that <function>date_bin</function> can truncate to an arbitrary interval.
</para>
<para>
The <parameter>stride</parameter> interval must be greater than zero and
cannot contain units of month or larger.
</para>
</sect2>
<sect2 id="functions-datetime-zoneconvert">
<title><literal>AT TIME ZONE</literal> and <literal>AT LOCAL</literal></title>
<indexterm>
<primary>time zone</primary>
<secondary>conversion</secondary>
</indexterm>
<indexterm>
<primary>AT TIME ZONE</primary>
</indexterm>
<indexterm>
<primary>AT LOCAL</primary>
</indexterm>
<para>
The <literal>AT TIME ZONE</literal> operator converts time
stamp <emphasis>without</emphasis> time zone to/from
time stamp <emphasis>with</emphasis> time zone, and
<type>time with time zone</type> values to different time
zones. <xref linkend="functions-datetime-zoneconvert-table"/> shows its
variants.
</para>
<table id="functions-datetime-zoneconvert-table">
<title><literal>AT TIME ZONE</literal> and <literal>AT LOCAL</literal> Variants</title>
<tgroup cols="1">
<thead>
<row>
<entry role="func_table_entry"><para role="func_signature">
Operator
</para>
<para>
Description
</para>
<para>
Example(s)
</para></entry>
</row>
</thead>
<tbody>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>timestamp without time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable>
<returnvalue>timestamp with time zone</returnvalue>
</para>
<para>
Converts given time stamp <emphasis>without</emphasis> time zone to
time stamp <emphasis>with</emphasis> time zone, assuming the given
value is in the named time zone.
</para>
<para>
<literal>timestamp '2001-02-16 20:38:40' at time zone 'America/Denver'</literal>
<returnvalue>2001-02-17 03:38:40+00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>timestamp without time zone</type> <literal>AT LOCAL</literal>
<returnvalue>timestamp with time zone</returnvalue>
</para>
<para>
Converts given time stamp <emphasis>without</emphasis> time zone to
time stamp <emphasis>with</emphasis> the session's
<varname>TimeZone</varname> value as time zone.
</para>
<para>
<literal>timestamp '2001-02-16 20:38:40' at local</literal>
<returnvalue>2001-02-17 03:38:40+00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>timestamp with time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable>
<returnvalue>timestamp without time zone</returnvalue>
</para>
<para>
Converts given time stamp <emphasis>with</emphasis> time zone to
time stamp <emphasis>without</emphasis> time zone, as the time would
appear in that zone.
</para>
<para>
<literal>timestamp with time zone '2001-02-16 20:38:40-05' at time zone 'America/Denver'</literal>
<returnvalue>2001-02-16 18:38:40</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>timestamp with time zone</type> <literal>AT LOCAL</literal>
<returnvalue>timestamp without time zone</returnvalue>
</para>
<para>
Converts given time stamp <emphasis>with</emphasis> time zone to
time stamp <emphasis>without</emphasis> time zone, as the time would
appear with the session's <varname>TimeZone</varname> value as time zone.
</para>
<para>
<literal>timestamp with time zone '2001-02-16 20:38:40-05' at local</literal>
<returnvalue>2001-02-16 18:38:40</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>time with time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable>
<returnvalue>time with time zone</returnvalue>
</para>
<para>
Converts given time <emphasis>with</emphasis> time zone to a new time
zone. Since no date is supplied, this uses the currently active UTC
offset for the named destination zone.
</para>
<para>
<literal>time with time zone '05:34:17-05' at time zone 'UTC'</literal>
<returnvalue>10:34:17+00</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<type>time with time zone</type> <literal>AT LOCAL</literal>
<returnvalue>time with time zone</returnvalue>
</para>
<para>
Converts given time <emphasis>with</emphasis> time zone to a new time
zone. Since no date is supplied, this uses the currently active UTC
offset for the session's <varname>TimeZone</varname> value.
</para>
<para>
Assuming the session's <varname>TimeZone</varname> is set to <literal>UTC</literal>:
</para>
<para>
<literal>time with time zone '05:34:17-05' at local</literal>
<returnvalue>10:34:17+00</returnvalue>
</para></entry>
</row>
</tbody>
</tgroup>
</table>
<para>
In these expressions, the desired time zone <replaceable>zone</replaceable> can be
specified either as a text value (e.g., <literal>'America/Los_Angeles'</literal>)
or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
In the text case, a time zone name can be specified in any of the ways
described in <xref linkend="datatype-timezones"/>.
The interval case is only useful for zones that have fixed offsets from
UTC, so it is not very common in practice.
</para>
<para>
The syntax <literal>AT LOCAL</literal> may be used as shorthand for
<literal>AT TIME ZONE <replaceable>local</replaceable></literal>, where
<replaceable>local</replaceable> is the session's
<varname>TimeZone</varname> value.
</para>
<para>
Examples (assuming the current <xref linkend="guc-timezone"/> setting
is <literal>America/Los_Angeles</literal>):
<screen>
SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'America/Denver';
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'America/Denver';
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'Asia/Tokyo' AT TIME ZONE 'America/Chicago';
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 05:38:40</computeroutput>
SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT LOCAL;
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 17:38:40</computeroutput>
SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE '+05';
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:38:40</computeroutput>
SELECT TIME WITH TIME ZONE '20:38:40-05' AT LOCAL;
<lineannotation>Result: </lineannotation><computeroutput>17:38:40</computeroutput>
</screen>
The first example adds a time zone to a value that lacks it, and
displays the value using the current <varname>TimeZone</varname>
setting. The second example shifts the time stamp with time zone value
to the specified time zone, and returns the value without a time zone.
This allows storage and display of values different from the current
<varname>TimeZone</varname> setting. The third example converts
Tokyo time to Chicago time. The fourth example shifts the time stamp
with time zone value to the time zone currently specified by the
<varname>TimeZone</varname> setting and returns the value without a
time zone. The fifth example demonstrates that the sign in a POSIX-style
time zone specification has the opposite meaning of the sign in an
ISO-8601 datetime literal, as described in <xref linkend="datatype-timezones"/>
and <xref linkend="datetime-appendix"/>.
</para>
<para>
The sixth example is a cautionary tale. Due to the fact that there is no
date associated with the input value, the conversion is made using the
current date of the session. Therefore, this static example may show a wrong
result depending on the time of the year it is viewed because
<literal>'America/Los_Angeles'</literal> observes Daylight Savings Time.
</para>
<para>
The function <literal><function>timezone</function>(<replaceable>zone</replaceable>,
<replaceable>timestamp</replaceable>)</literal> is equivalent to the SQL-conforming construct
<literal><replaceable>timestamp</replaceable> AT TIME ZONE
<replaceable>zone</replaceable></literal>.
</para>
<para>
The function <literal><function>timezone</function>(<replaceable>zone</replaceable>,
<replaceable>time</replaceable>)</literal> is equivalent to the SQL-conforming construct
<literal><replaceable>time</replaceable> AT TIME ZONE
<replaceable>zone</replaceable></literal>.
</para>
<para>
The function <literal><function>timezone</function>(<replaceable>timestamp</replaceable>)</literal>
is equivalent to the SQL-conforming construct <literal><replaceable>timestamp</replaceable>
AT LOCAL</literal>.
</para>
<para>
The function <literal><function>timezone</function>(<replaceable>time</replaceable>)</literal>
is equivalent to the SQL-conforming construct <literal><replaceable>time</replaceable>
AT LOCAL</literal>.
</para>
</sect2>
<sect2 id="functions-datetime-current">
<title>Current Date/Time</title>
<indexterm>
<primary>date</primary>
<secondary>current</secondary>
</indexterm>
<indexterm>
<primary>time</primary>
<secondary>current</secondary>
</indexterm>
<para>
<productname>PostgreSQL</productname> provides a number of functions
that return values related to the current date and time. These
SQL-standard functions all return values based on the start time of
the current transaction:
<synopsis>
CURRENT_DATE
CURRENT_TIME
CURRENT_TIMESTAMP
CURRENT_TIME(<replaceable>precision</replaceable>)
CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
LOCALTIME
LOCALTIMESTAMP
LOCALTIME(<replaceable>precision</replaceable>)
LOCALTIMESTAMP(<replaceable>precision</replaceable>)
</synopsis>
</para>
<para>
<function>CURRENT_TIME</function> and
<function>CURRENT_TIMESTAMP</function> deliver values with time zone;
<function>LOCALTIME</function> and
<function>LOCALTIMESTAMP</function> deliver values without time zone.
</para>
<para>
<function>CURRENT_TIME</function>,
<function>CURRENT_TIMESTAMP</function>,
<function>LOCALTIME</function>, and
<function>LOCALTIMESTAMP</function>
can optionally take
a precision parameter, which causes the result to be rounded
to that many fractional digits in the seconds field. Without a precision parameter,
the result is given to the full available precision.
</para>
<para>
Some examples:
<screen>
SELECT CURRENT_TIME;
<lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
SELECT CURRENT_DATE;
<lineannotation>Result: </lineannotation><computeroutput>2019-12-23</computeroutput>
SELECT CURRENT_TIMESTAMP;
<lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.662522-05</computeroutput>
SELECT CURRENT_TIMESTAMP(2);
<lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.66-05</computeroutput>
SELECT LOCALTIMESTAMP;
<lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.662522</computeroutput>
</screen>
</para>
<para>
Since these functions return
the start time of the current transaction, their values do not
change during the transaction. This is considered a feature:
the intent is to allow a single transaction to have a consistent
notion of the <quote>current</quote> time, so that multiple
modifications within the same transaction bear the same
time stamp.
</para>
<note>
<para>
Other database systems might advance these values more
frequently.
</para>
</note>
<para>
<productname>PostgreSQL</productname> also provides functions that
return the start time of the current statement, as well as the actual
current time at the instant the function is called. The complete list
of non-SQL-standard time functions is:
<synopsis>
transaction_timestamp()
statement_timestamp()
clock_timestamp()
timeofday()
now()
</synopsis>
</para>
<para>
<function>transaction_timestamp()</function> is equivalent to
<function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
what it returns.
<function>statement_timestamp()</function> returns the start time of the current
statement (more specifically, the time of receipt of the latest command
message from the client).
<function>statement_timestamp()</function> and <function>transaction_timestamp()</function>
return the same value during the first statement of a transaction, but might
differ during subsequent statements.
<function>clock_timestamp()</function> returns the actual current time, and
therefore its value changes even within a single SQL statement.
<function>timeofday()</function> is a historical
<productname>PostgreSQL</productname> function. Like
<function>clock_timestamp()</function>, it returns the actual current time,
but as a formatted <type>text</type> string rather than a <type>timestamp
with time zone</type> value.
<function>now()</function> is a traditional <productname>PostgreSQL</productname>
equivalent to <function>transaction_timestamp()</function>.
</para>
<para>
All the date/time data types also accept the special literal value
<literal>now</literal> to specify the current date and time (again,
interpreted as the transaction start time). Thus,
the following three all return the same result:
<programlisting>
SELECT CURRENT_TIMESTAMP;
SELECT now();
SELECT TIMESTAMP 'now'; -- but see tip below
</programlisting>
</para>
<tip>
<para>
Do not use the third form when specifying a value to be evaluated later,
for example in a <literal>DEFAULT</literal> clause for a table column.
The system will convert <literal>now</literal>
to a <type>timestamp</type> as soon as the constant is parsed, so that when
the default value is needed,
the time of the table creation would be used! The first two
forms will not be evaluated until the default value is used,
because they are function calls. Thus they will give the desired
behavior of defaulting to the time of row insertion.
(See also <xref linkend="datatype-datetime-special-values"/>.)
</para>
</tip>
</sect2>
<sect2 id="functions-datetime-delay">
<title>Delaying Execution</title>
<indexterm>
<primary>pg_sleep</primary>
</indexterm>
<indexterm>
<primary>pg_sleep_for</primary>
</indexterm>
<indexterm>
<primary>pg_sleep_until</primary>
</indexterm>
<indexterm>
<primary>sleep</primary>
</indexterm>
<indexterm>
<primary>delay</primary>
</indexterm>
<para>
The following functions are available to delay execution of the server
process:
<synopsis>
pg_sleep ( <type>double precision</type> )
pg_sleep_for ( <type>interval</type> )
pg_sleep_until ( <type>timestamp with time zone</type> )
</synopsis>
<function>pg_sleep</function> makes the current session's process
sleep until the given number of seconds have
elapsed. Fractional-second delays can be specified.
<function>pg_sleep_for</function> is a convenience function to
allow the sleep time to be specified as an <type>interval</type>.
<function>pg_sleep_until</function> is a convenience function for when
a specific wake-up time is desired.
For example:
<programlisting>
SELECT pg_sleep(1.5);
SELECT pg_sleep_for('5 minutes');
SELECT pg_sleep_until('tomorrow 03:00');
</programlisting>
</para>
<note>
<para>
The effective resolution of the sleep interval is platform-specific;
0.01 seconds is a common value. The sleep delay will be at least as long
as specified. It might be longer depending on factors such as server load.
In particular, <function>pg_sleep_until</function> is not guaranteed to
wake up exactly at the specified time, but it will not wake up any earlier.
</para>
</note>
<warning>
<para>
Make sure that your session does not hold more locks than necessary
when calling <function>pg_sleep</function> or its variants. Otherwise
other sessions might have to wait for your sleeping process, slowing down
the entire system.
</para>
</warning>
</sect2>
</sect1>
|