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
|
<?xml version="1.0" encoding="UTF-8" standalone="no"?>
<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>9.9. Date/Time Functions and Operators</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><link rel="prev" href="functions-formatting.html" title="9.8. Data Type Formatting Functions" /><link rel="next" href="functions-enum.html" title="9.10. Enum Support Functions" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">9.9. Date/Time Functions and Operators</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="functions-formatting.html" title="9.8. Data Type Formatting Functions">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="functions.html" title="Chapter 9. Functions and Operators">Up</a></td><th width="60%" align="center">Chapter 9. Functions and Operators</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 16.3 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="functions-enum.html" title="9.10. Enum Support Functions">Next</a></td></tr></table><hr /></div><div class="sect1" id="FUNCTIONS-DATETIME"><div class="titlepage"><div><div><h2 class="title" style="clear: both">9.9. Date/Time Functions and Operators <a href="#FUNCTIONS-DATETIME" class="id_link">#</a></h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="functions-datetime.html#FUNCTIONS-DATETIME-EXTRACT">9.9.1. <code class="function">EXTRACT</code>, <code class="function">date_part</code></a></span></dt><dt><span class="sect2"><a href="functions-datetime.html#FUNCTIONS-DATETIME-TRUNC">9.9.2. <code class="function">date_trunc</code></a></span></dt><dt><span class="sect2"><a href="functions-datetime.html#FUNCTIONS-DATETIME-BIN">9.9.3. <code class="function">date_bin</code></a></span></dt><dt><span class="sect2"><a href="functions-datetime.html#FUNCTIONS-DATETIME-ZONECONVERT">9.9.4. <code class="literal">AT TIME ZONE</code></a></span></dt><dt><span class="sect2"><a href="functions-datetime.html#FUNCTIONS-DATETIME-CURRENT">9.9.5. Current Date/Time</a></span></dt><dt><span class="sect2"><a href="functions-datetime.html#FUNCTIONS-DATETIME-DELAY">9.9.6. Delaying Execution</a></span></dt></dl></div><p>
<a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-TABLE" title="Table 9.33. Date/Time Functions">Table 9.33</a> shows the available
functions for date/time value processing, with details appearing in
the following subsections. <a class="xref" href="functions-datetime.html#OPERATORS-DATETIME-TABLE" title="Table 9.32. Date/Time Operators">Table 9.32</a> illustrates the behaviors of
the basic arithmetic operators (<code class="literal">+</code>,
<code class="literal">*</code>, etc.). For formatting functions, refer to
<a class="xref" href="functions-formatting.html" title="9.8. Data Type Formatting Functions">Section 9.8</a>. You should be familiar with
the background information on date/time data types from <a class="xref" href="datatype-datetime.html" title="8.5. Date/Time Types">Section 8.5</a>.
</p><p>
In addition, the usual comparison operators shown in
<a class="xref" href="functions-comparison.html#FUNCTIONS-COMPARISON-OP-TABLE" title="Table 9.1. Comparison Operators">Table 9.1</a> 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 <a class="xref" href="runtime-config-client.html#GUC-TIMEZONE">TimeZone</a> 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 <code class="varname">TimeZone</code> zone when comparing it
to a timestamp.
</p><p>
All the functions and operators described below that take <code class="type">time</code> or <code class="type">timestamp</code>
inputs actually come in two variants: one that takes <code class="type">time with time zone</code> or <code class="type">timestamp
with time zone</code>, and one that takes <code class="type">time without time zone</code> or <code class="type">timestamp without time zone</code>.
For brevity, these variants are not shown separately. Also, the
<code class="literal">+</code> and <code class="literal">*</code> operators come in commutative pairs (for
example both <code class="type">date</code> <code class="literal">+</code> <code class="type">integer</code>
and <code class="type">integer</code> <code class="literal">+</code> <code class="type">date</code>); we show
only one of each such pair.
</p><div class="table" id="OPERATORS-DATETIME-TABLE"><p class="title"><strong>Table 9.32. Date/Time Operators</strong></p><div class="table-contents"><table class="table" summary="Date/Time Operators" border="1"><colgroup><col /></colgroup><thead><tr><th class="func_table_entry"><p class="func_signature">
Operator
</p>
<p>
Description
</p>
<p>
Example(s)
</p></th></tr></thead><tbody><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">date</code> <code class="literal">+</code> <code class="type">integer</code>
→ <code class="returnvalue">date</code>
</p>
<p>
Add a number of days to a date
</p>
<p>
<code class="literal">date '2001-09-28' + 7</code>
→ <code class="returnvalue">2001-10-05</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">date</code> <code class="literal">+</code> <code class="type">interval</code>
→ <code class="returnvalue">timestamp</code>
</p>
<p>
Add an interval to a date
</p>
<p>
<code class="literal">date '2001-09-28' + interval '1 hour'</code>
→ <code class="returnvalue">2001-09-28 01:00:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">date</code> <code class="literal">+</code> <code class="type">time</code>
→ <code class="returnvalue">timestamp</code>
</p>
<p>
Add a time-of-day to a date
</p>
<p>
<code class="literal">date '2001-09-28' + time '03:00'</code>
→ <code class="returnvalue">2001-09-28 03:00:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">interval</code> <code class="literal">+</code> <code class="type">interval</code>
→ <code class="returnvalue">interval</code>
</p>
<p>
Add intervals
</p>
<p>
<code class="literal">interval '1 day' + interval '1 hour'</code>
→ <code class="returnvalue">1 day 01:00:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">timestamp</code> <code class="literal">+</code> <code class="type">interval</code>
→ <code class="returnvalue">timestamp</code>
</p>
<p>
Add an interval to a timestamp
</p>
<p>
<code class="literal">timestamp '2001-09-28 01:00' + interval '23 hours'</code>
→ <code class="returnvalue">2001-09-29 00:00:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">time</code> <code class="literal">+</code> <code class="type">interval</code>
→ <code class="returnvalue">time</code>
</p>
<p>
Add an interval to a time
</p>
<p>
<code class="literal">time '01:00' + interval '3 hours'</code>
→ <code class="returnvalue">04:00:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="literal">-</code> <code class="type">interval</code>
→ <code class="returnvalue">interval</code>
</p>
<p>
Negate an interval
</p>
<p>
<code class="literal">- interval '23 hours'</code>
→ <code class="returnvalue">-23:00:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">date</code> <code class="literal">-</code> <code class="type">date</code>
→ <code class="returnvalue">integer</code>
</p>
<p>
Subtract dates, producing the number of days elapsed
</p>
<p>
<code class="literal">date '2001-10-01' - date '2001-09-28'</code>
→ <code class="returnvalue">3</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">date</code> <code class="literal">-</code> <code class="type">integer</code>
→ <code class="returnvalue">date</code>
</p>
<p>
Subtract a number of days from a date
</p>
<p>
<code class="literal">date '2001-10-01' - 7</code>
→ <code class="returnvalue">2001-09-24</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">date</code> <code class="literal">-</code> <code class="type">interval</code>
→ <code class="returnvalue">timestamp</code>
</p>
<p>
Subtract an interval from a date
</p>
<p>
<code class="literal">date '2001-09-28' - interval '1 hour'</code>
→ <code class="returnvalue">2001-09-27 23:00:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">time</code> <code class="literal">-</code> <code class="type">time</code>
→ <code class="returnvalue">interval</code>
</p>
<p>
Subtract times
</p>
<p>
<code class="literal">time '05:00' - time '03:00'</code>
→ <code class="returnvalue">02:00:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">time</code> <code class="literal">-</code> <code class="type">interval</code>
→ <code class="returnvalue">time</code>
</p>
<p>
Subtract an interval from a time
</p>
<p>
<code class="literal">time '05:00' - interval '2 hours'</code>
→ <code class="returnvalue">03:00:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">timestamp</code> <code class="literal">-</code> <code class="type">interval</code>
→ <code class="returnvalue">timestamp</code>
</p>
<p>
Subtract an interval from a timestamp
</p>
<p>
<code class="literal">timestamp '2001-09-28 23:00' - interval '23 hours'</code>
→ <code class="returnvalue">2001-09-28 00:00:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">interval</code> <code class="literal">-</code> <code class="type">interval</code>
→ <code class="returnvalue">interval</code>
</p>
<p>
Subtract intervals
</p>
<p>
<code class="literal">interval '1 day' - interval '1 hour'</code>
→ <code class="returnvalue">1 day -01:00:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">timestamp</code> <code class="literal">-</code> <code class="type">timestamp</code>
→ <code class="returnvalue">interval</code>
</p>
<p>
Subtract timestamps (converting 24-hour intervals into days,
similarly to <a class="link" href="functions-datetime.html#FUNCTION-JUSTIFY-HOURS"><code class="function">justify_hours()</code></a>)
</p>
<p>
<code class="literal">timestamp '2001-09-29 03:00' - timestamp '2001-07-27 12:00'</code>
→ <code class="returnvalue">63 days 15:00:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">interval</code> <code class="literal">*</code> <code class="type">double precision</code>
→ <code class="returnvalue">interval</code>
</p>
<p>
Multiply an interval by a scalar
</p>
<p>
<code class="literal">interval '1 second' * 900</code>
→ <code class="returnvalue">00:15:00</code>
</p>
<p>
<code class="literal">interval '1 day' * 21</code>
→ <code class="returnvalue">21 days</code>
</p>
<p>
<code class="literal">interval '1 hour' * 3.5</code>
→ <code class="returnvalue">03:30:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">interval</code> <code class="literal">/</code> <code class="type">double precision</code>
→ <code class="returnvalue">interval</code>
</p>
<p>
Divide an interval by a scalar
</p>
<p>
<code class="literal">interval '1 hour' / 1.5</code>
→ <code class="returnvalue">00:40:00</code>
</p></td></tr></tbody></table></div></div><br class="table-break" /><div class="table" id="FUNCTIONS-DATETIME-TABLE"><p class="title"><strong>Table 9.33. Date/Time Functions</strong></p><div class="table-contents"><table class="table" summary="Date/Time Functions" border="1"><colgroup><col /></colgroup><thead><tr><th class="func_table_entry"><p class="func_signature">
Function
</p>
<p>
Description
</p>
<p>
Example(s)
</p></th></tr></thead><tbody><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.1.1.1.1" class="indexterm"></a>
<code class="function">age</code> ( <code class="type">timestamp</code>, <code class="type">timestamp</code> )
→ <code class="returnvalue">interval</code>
</p>
<p>
Subtract arguments, producing a <span class="quote">“<span class="quote">symbolic</span>”</span> result that
uses years and months, rather than just days
</p>
<p>
<code class="literal">age(timestamp '2001-04-10', timestamp '1957-06-13')</code>
→ <code class="returnvalue">43 years 9 mons 27 days</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="function">age</code> ( <code class="type">timestamp</code> )
→ <code class="returnvalue">interval</code>
</p>
<p>
Subtract argument from <code class="function">current_date</code> (at midnight)
</p>
<p>
<code class="literal">age(timestamp '1957-06-13')</code>
→ <code class="returnvalue">62 years 6 mons 10 days</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.3.1.1.1" class="indexterm"></a>
<code class="function">clock_timestamp</code> ( )
→ <code class="returnvalue">timestamp with time zone</code>
</p>
<p>
Current date and time (changes during statement execution);
see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-CURRENT" title="9.9.5. Current Date/Time">Section 9.9.5</a>
</p>
<p>
<code class="literal">clock_timestamp()</code>
→ <code class="returnvalue">2019-12-23 14:39:53.662522-05</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.4.1.1.1" class="indexterm"></a>
<code class="function">current_date</code>
→ <code class="returnvalue">date</code>
</p>
<p>
Current date; see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-CURRENT" title="9.9.5. Current Date/Time">Section 9.9.5</a>
</p>
<p>
<code class="literal">current_date</code>
→ <code class="returnvalue">2019-12-23</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.5.1.1.1" class="indexterm"></a>
<code class="function">current_time</code>
→ <code class="returnvalue">time with time zone</code>
</p>
<p>
Current time of day; see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-CURRENT" title="9.9.5. Current Date/Time">Section 9.9.5</a>
</p>
<p>
<code class="literal">current_time</code>
→ <code class="returnvalue">14:39:53.662522-05</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="function">current_time</code> ( <code class="type">integer</code> )
→ <code class="returnvalue">time with time zone</code>
</p>
<p>
Current time of day, with limited precision;
see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-CURRENT" title="9.9.5. Current Date/Time">Section 9.9.5</a>
</p>
<p>
<code class="literal">current_time(2)</code>
→ <code class="returnvalue">14:39:53.66-05</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.7.1.1.1" class="indexterm"></a>
<code class="function">current_timestamp</code>
→ <code class="returnvalue">timestamp with time zone</code>
</p>
<p>
Current date and time (start of current transaction);
see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-CURRENT" title="9.9.5. Current Date/Time">Section 9.9.5</a>
</p>
<p>
<code class="literal">current_timestamp</code>
→ <code class="returnvalue">2019-12-23 14:39:53.662522-05</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="function">current_timestamp</code> ( <code class="type">integer</code> )
→ <code class="returnvalue">timestamp with time zone</code>
</p>
<p>
Current date and time (start of current transaction), with limited precision;
see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-CURRENT" title="9.9.5. Current Date/Time">Section 9.9.5</a>
</p>
<p>
<code class="literal">current_timestamp(0)</code>
→ <code class="returnvalue">2019-12-23 14:39:53-05</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.9.1.1.1" class="indexterm"></a>
<code class="function">date_add</code> ( <code class="type">timestamp with time zone</code>, <code class="type">interval</code> [<span class="optional">, <code class="type">text</code> </span>] )
→ <code class="returnvalue">timestamp with time zone</code>
</p>
<p>
Add an <code class="type">interval</code> to a <code class="type">timestamp with time
zone</code>, computing times of day and daylight-savings adjustments
according to the time zone named by the third argument, or the
current <a class="xref" href="runtime-config-client.html#GUC-TIMEZONE">TimeZone</a> setting if that is omitted.
The form with two arguments is equivalent to the <code class="type">timestamp with
time zone</code> <code class="literal">+</code> <code class="type">interval</code> operator.
</p>
<p>
<code class="literal">date_add('2021-10-31 00:00:00+02'::timestamptz, '1 day'::interval, 'Europe/Warsaw')</code>
→ <code class="returnvalue">2021-10-31 23:00:00+00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="function">date_bin</code> ( <code class="type">interval</code>, <code class="type">timestamp</code>, <code class="type">timestamp</code> )
→ <code class="returnvalue">timestamp</code>
</p>
<p>
Bin input into specified interval aligned with specified origin; see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-BIN" title="9.9.3. date_bin">Section 9.9.3</a>
</p>
<p>
<code class="literal">date_bin('15 minutes', timestamp '2001-02-16 20:38:40', timestamp '2001-02-16 20:05:00')</code>
→ <code class="returnvalue">2001-02-16 20:35:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.11.1.1.1" class="indexterm"></a>
<code class="function">date_part</code> ( <code class="type">text</code>, <code class="type">timestamp</code> )
→ <code class="returnvalue">double precision</code>
</p>
<p>
Get timestamp subfield (equivalent to <code class="function">extract</code>);
see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-EXTRACT" title="9.9.1. EXTRACT, date_part">Section 9.9.1</a>
</p>
<p>
<code class="literal">date_part('hour', timestamp '2001-02-16 20:38:40')</code>
→ <code class="returnvalue">20</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="function">date_part</code> ( <code class="type">text</code>, <code class="type">interval</code> )
→ <code class="returnvalue">double precision</code>
</p>
<p>
Get interval subfield (equivalent to <code class="function">extract</code>);
see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-EXTRACT" title="9.9.1. EXTRACT, date_part">Section 9.9.1</a>
</p>
<p>
<code class="literal">date_part('month', interval '2 years 3 months')</code>
→ <code class="returnvalue">3</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.13.1.1.1" class="indexterm"></a>
<code class="function">date_subtract</code> ( <code class="type">timestamp with time zone</code>, <code class="type">interval</code> [<span class="optional">, <code class="type">text</code> </span>] )
→ <code class="returnvalue">timestamp with time zone</code>
</p>
<p>
Subtract an <code class="type">interval</code> from a <code class="type">timestamp with time
zone</code>, computing times of day and daylight-savings adjustments
according to the time zone named by the third argument, or the
current <a class="xref" href="runtime-config-client.html#GUC-TIMEZONE">TimeZone</a> setting if that is omitted.
The form with two arguments is equivalent to the <code class="type">timestamp with
time zone</code> <code class="literal">-</code> <code class="type">interval</code> operator.
</p>
<p>
<code class="literal">date_subtract('2021-11-01 00:00:00+01'::timestamptz, '1 day'::interval, 'Europe/Warsaw')</code>
→ <code class="returnvalue">2021-10-30 22:00:00+00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.14.1.1.1" class="indexterm"></a>
<code class="function">date_trunc</code> ( <code class="type">text</code>, <code class="type">timestamp</code> )
→ <code class="returnvalue">timestamp</code>
</p>
<p>
Truncate to specified precision; see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-TRUNC" title="9.9.2. date_trunc">Section 9.9.2</a>
</p>
<p>
<code class="literal">date_trunc('hour', timestamp '2001-02-16 20:38:40')</code>
→ <code class="returnvalue">2001-02-16 20:00:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="function">date_trunc</code> ( <code class="type">text</code>, <code class="type">timestamp with time zone</code>, <code class="type">text</code> )
→ <code class="returnvalue">timestamp with time zone</code>
</p>
<p>
Truncate to specified precision in the specified time zone; see
<a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-TRUNC" title="9.9.2. date_trunc">Section 9.9.2</a>
</p>
<p>
<code class="literal">date_trunc('day', timestamptz '2001-02-16 20:38:40+00', 'Australia/Sydney')</code>
→ <code class="returnvalue">2001-02-16 13:00:00+00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="function">date_trunc</code> ( <code class="type">text</code>, <code class="type">interval</code> )
→ <code class="returnvalue">interval</code>
</p>
<p>
Truncate to specified precision; see
<a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-TRUNC" title="9.9.2. date_trunc">Section 9.9.2</a>
</p>
<p>
<code class="literal">date_trunc('hour', interval '2 days 3 hours 40 minutes')</code>
→ <code class="returnvalue">2 days 03:00:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.17.1.1.1" class="indexterm"></a>
<code class="function">extract</code> ( <em class="parameter"><code>field</code></em> <code class="literal">from</code> <code class="type">timestamp</code> )
→ <code class="returnvalue">numeric</code>
</p>
<p>
Get timestamp subfield; see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-EXTRACT" title="9.9.1. EXTRACT, date_part">Section 9.9.1</a>
</p>
<p>
<code class="literal">extract(hour from timestamp '2001-02-16 20:38:40')</code>
→ <code class="returnvalue">20</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="function">extract</code> ( <em class="parameter"><code>field</code></em> <code class="literal">from</code> <code class="type">interval</code> )
→ <code class="returnvalue">numeric</code>
</p>
<p>
Get interval subfield; see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-EXTRACT" title="9.9.1. EXTRACT, date_part">Section 9.9.1</a>
</p>
<p>
<code class="literal">extract(month from interval '2 years 3 months')</code>
→ <code class="returnvalue">3</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.19.1.1.1" class="indexterm"></a>
<code class="function">isfinite</code> ( <code class="type">date</code> )
→ <code class="returnvalue">boolean</code>
</p>
<p>
Test for finite date (not +/-infinity)
</p>
<p>
<code class="literal">isfinite(date '2001-02-16')</code>
→ <code class="returnvalue">true</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="function">isfinite</code> ( <code class="type">timestamp</code> )
→ <code class="returnvalue">boolean</code>
</p>
<p>
Test for finite timestamp (not +/-infinity)
</p>
<p>
<code class="literal">isfinite(timestamp 'infinity')</code>
→ <code class="returnvalue">false</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="function">isfinite</code> ( <code class="type">interval</code> )
→ <code class="returnvalue">boolean</code>
</p>
<p>
Test for finite interval (currently always true)
</p>
<p>
<code class="literal">isfinite(interval '4 hours')</code>
→ <code class="returnvalue">true</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="FUNCTION-JUSTIFY-DAYS" class="indexterm"></a>
<code class="function">justify_days</code> ( <code class="type">interval</code> )
→ <code class="returnvalue">interval</code>
</p>
<p>
Adjust interval, converting 30-day time periods to months
</p>
<p>
<code class="literal">justify_days(interval '1 year 65 days')</code>
→ <code class="returnvalue">1 year 2 mons 5 days</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="FUNCTION-JUSTIFY-HOURS" class="indexterm"></a>
<code class="function">justify_hours</code> ( <code class="type">interval</code> )
→ <code class="returnvalue">interval</code>
</p>
<p>
Adjust interval, converting 24-hour time periods to days
</p>
<p>
<code class="literal">justify_hours(interval '50 hours 10 minutes')</code>
→ <code class="returnvalue">2 days 02:10:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.24.1.1.1" class="indexterm"></a>
<code class="function">justify_interval</code> ( <code class="type">interval</code> )
→ <code class="returnvalue">interval</code>
</p>
<p>
Adjust interval using <code class="function">justify_days</code>
and <code class="function">justify_hours</code>, with additional sign
adjustments
</p>
<p>
<code class="literal">justify_interval(interval '1 mon -1 hour')</code>
→ <code class="returnvalue">29 days 23:00:00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.25.1.1.1" class="indexterm"></a>
<code class="function">localtime</code>
→ <code class="returnvalue">time</code>
</p>
<p>
Current time of day;
see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-CURRENT" title="9.9.5. Current Date/Time">Section 9.9.5</a>
</p>
<p>
<code class="literal">localtime</code>
→ <code class="returnvalue">14:39:53.662522</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="function">localtime</code> ( <code class="type">integer</code> )
→ <code class="returnvalue">time</code>
</p>
<p>
Current time of day, with limited precision;
see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-CURRENT" title="9.9.5. Current Date/Time">Section 9.9.5</a>
</p>
<p>
<code class="literal">localtime(0)</code>
→ <code class="returnvalue">14:39:53</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.27.1.1.1" class="indexterm"></a>
<code class="function">localtimestamp</code>
→ <code class="returnvalue">timestamp</code>
</p>
<p>
Current date and time (start of current transaction);
see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-CURRENT" title="9.9.5. Current Date/Time">Section 9.9.5</a>
</p>
<p>
<code class="literal">localtimestamp</code>
→ <code class="returnvalue">2019-12-23 14:39:53.662522</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="function">localtimestamp</code> ( <code class="type">integer</code> )
→ <code class="returnvalue">timestamp</code>
</p>
<p>
Current date and time (start of current
transaction), with limited precision;
see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-CURRENT" title="9.9.5. Current Date/Time">Section 9.9.5</a>
</p>
<p>
<code class="literal">localtimestamp(2)</code>
→ <code class="returnvalue">2019-12-23 14:39:53.66</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.29.1.1.1" class="indexterm"></a>
<code class="function">make_date</code> ( <em class="parameter"><code>year</code></em> <code class="type">int</code>,
<em class="parameter"><code>month</code></em> <code class="type">int</code>,
<em class="parameter"><code>day</code></em> <code class="type">int</code> )
→ <code class="returnvalue">date</code>
</p>
<p>
Create date from year, month and day fields
(negative years signify BC)
</p>
<p>
<code class="literal">make_date(2013, 7, 15)</code>
→ <code class="returnvalue">2013-07-15</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature"><a id="id-1.5.8.15.6.2.2.30.1.1.1" class="indexterm"></a>
<code class="function">make_interval</code> ( [<span class="optional"> <em class="parameter"><code>years</code></em> <code class="type">int</code>
[<span class="optional">, <em class="parameter"><code>months</code></em> <code class="type">int</code>
[<span class="optional">, <em class="parameter"><code>weeks</code></em> <code class="type">int</code>
[<span class="optional">, <em class="parameter"><code>days</code></em> <code class="type">int</code>
[<span class="optional">, <em class="parameter"><code>hours</code></em> <code class="type">int</code>
[<span class="optional">, <em class="parameter"><code>mins</code></em> <code class="type">int</code>
[<span class="optional">, <em class="parameter"><code>secs</code></em> <code class="type">double precision</code>
</span>]</span>]</span>]</span>]</span>]</span>]</span>] )
→ <code class="returnvalue">interval</code>
</p>
<p>
Create interval from years, months, weeks, days, hours, minutes and
seconds fields, each of which can default to zero
</p>
<p>
<code class="literal">make_interval(days => 10)</code>
→ <code class="returnvalue">10 days</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.31.1.1.1" class="indexterm"></a>
<code class="function">make_time</code> ( <em class="parameter"><code>hour</code></em> <code class="type">int</code>,
<em class="parameter"><code>min</code></em> <code class="type">int</code>,
<em class="parameter"><code>sec</code></em> <code class="type">double precision</code> )
→ <code class="returnvalue">time</code>
</p>
<p>
Create time from hour, minute and seconds fields
</p>
<p>
<code class="literal">make_time(8, 15, 23.5)</code>
→ <code class="returnvalue">08:15:23.5</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.32.1.1.1" class="indexterm"></a>
<code class="function">make_timestamp</code> ( <em class="parameter"><code>year</code></em> <code class="type">int</code>,
<em class="parameter"><code>month</code></em> <code class="type">int</code>,
<em class="parameter"><code>day</code></em> <code class="type">int</code>,
<em class="parameter"><code>hour</code></em> <code class="type">int</code>,
<em class="parameter"><code>min</code></em> <code class="type">int</code>,
<em class="parameter"><code>sec</code></em> <code class="type">double precision</code> )
→ <code class="returnvalue">timestamp</code>
</p>
<p>
Create timestamp from year, month, day, hour, minute and seconds fields
(negative years signify BC)
</p>
<p>
<code class="literal">make_timestamp(2013, 7, 15, 8, 15, 23.5)</code>
→ <code class="returnvalue">2013-07-15 08:15:23.5</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.33.1.1.1" class="indexterm"></a>
<code class="function">make_timestamptz</code> ( <em class="parameter"><code>year</code></em> <code class="type">int</code>,
<em class="parameter"><code>month</code></em> <code class="type">int</code>,
<em class="parameter"><code>day</code></em> <code class="type">int</code>,
<em class="parameter"><code>hour</code></em> <code class="type">int</code>,
<em class="parameter"><code>min</code></em> <code class="type">int</code>,
<em class="parameter"><code>sec</code></em> <code class="type">double precision</code>
[<span class="optional">, <em class="parameter"><code>timezone</code></em> <code class="type">text</code> </span>] )
→ <code class="returnvalue">timestamp with time zone</code>
</p>
<p>
Create timestamp with time zone from year, month, day, hour, minute
and seconds fields (negative years signify BC).
If <em class="parameter"><code>timezone</code></em> is not
specified, the current time zone is used; the examples assume the
session time zone is <code class="literal">Europe/London</code>
</p>
<p>
<code class="literal">make_timestamptz(2013, 7, 15, 8, 15, 23.5)</code>
→ <code class="returnvalue">2013-07-15 08:15:23.5+01</code>
</p>
<p>
<code class="literal">make_timestamptz(2013, 7, 15, 8, 15, 23.5, 'America/New_York')</code>
→ <code class="returnvalue">2013-07-15 13:15:23.5+01</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.34.1.1.1" class="indexterm"></a>
<code class="function">now</code> ( )
→ <code class="returnvalue">timestamp with time zone</code>
</p>
<p>
Current date and time (start of current transaction);
see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-CURRENT" title="9.9.5. Current Date/Time">Section 9.9.5</a>
</p>
<p>
<code class="literal">now()</code>
→ <code class="returnvalue">2019-12-23 14:39:53.662522-05</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.35.1.1.1" class="indexterm"></a>
<code class="function">statement_timestamp</code> ( )
→ <code class="returnvalue">timestamp with time zone</code>
</p>
<p>
Current date and time (start of current statement);
see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-CURRENT" title="9.9.5. Current Date/Time">Section 9.9.5</a>
</p>
<p>
<code class="literal">statement_timestamp()</code>
→ <code class="returnvalue">2019-12-23 14:39:53.662522-05</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.36.1.1.1" class="indexterm"></a>
<code class="function">timeofday</code> ( )
→ <code class="returnvalue">text</code>
</p>
<p>
Current date and time
(like <code class="function">clock_timestamp</code>, but as a <code class="type">text</code> string);
see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-CURRENT" title="9.9.5. Current Date/Time">Section 9.9.5</a>
</p>
<p>
<code class="literal">timeofday()</code>
→ <code class="returnvalue">Mon Dec 23 14:39:53.662522 2019 EST</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.37.1.1.1" class="indexterm"></a>
<code class="function">transaction_timestamp</code> ( )
→ <code class="returnvalue">timestamp with time zone</code>
</p>
<p>
Current date and time (start of current transaction);
see <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-CURRENT" title="9.9.5. Current Date/Time">Section 9.9.5</a>
</p>
<p>
<code class="literal">transaction_timestamp()</code>
→ <code class="returnvalue">2019-12-23 14:39:53.662522-05</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.15.6.2.2.38.1.1.1" class="indexterm"></a>
<code class="function">to_timestamp</code> ( <code class="type">double precision</code> )
→ <code class="returnvalue">timestamp with time zone</code>
</p>
<p>
Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to
timestamp with time zone
</p>
<p>
<code class="literal">to_timestamp(1284352323)</code>
→ <code class="returnvalue">2010-09-13 04:32:03+00</code>
</p></td></tr></tbody></table></div></div><br class="table-break" /><p>
<a id="id-1.5.8.15.7.1" class="indexterm"></a>
In addition to these functions, the SQL <code class="literal">OVERLAPS</code> operator is
supported:
</p><pre class="synopsis">
(<em class="replaceable"><code>start1</code></em>, <em class="replaceable"><code>end1</code></em>) OVERLAPS (<em class="replaceable"><code>start2</code></em>, <em class="replaceable"><code>end2</code></em>)
(<em class="replaceable"><code>start1</code></em>, <em class="replaceable"><code>length1</code></em>) OVERLAPS (<em class="replaceable"><code>start2</code></em>, <em class="replaceable"><code>length2</code></em>)
</pre><p>
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; <code class="literal">OVERLAPS</code> automatically takes the earlier value
of the pair as the start. Each time period is considered to
represent the half-open interval <em class="replaceable"><code>start</code></em> <code class="literal"><=</code>
<em class="replaceable"><code>time</code></em> <code class="literal"><</code> <em class="replaceable"><code>end</code></em>, unless
<em class="replaceable"><code>start</code></em> and <em class="replaceable"><code>end</code></em> 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.
</p><pre class="screen">
SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
(DATE '2001-10-30', DATE '2002-10-30');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">true</code>
SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
(DATE '2001-10-30', DATE '2002-10-30');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">false</code>
SELECT (DATE '2001-10-29', DATE '2001-10-30') OVERLAPS
(DATE '2001-10-30', DATE '2001-10-31');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">false</code>
SELECT (DATE '2001-10-30', DATE '2001-10-30') OVERLAPS
(DATE '2001-10-30', DATE '2001-10-31');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">true</code>
</pre><p>
When adding an <code class="type">interval</code> value to (or subtracting an
<code class="type">interval</code> value from) a <code class="type">timestamp</code>
or <code class="type">timestamp with time zone</code> value, the months, days, and
microseconds fields of the <code class="type">interval</code> 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 <code class="type">timestamp with time zone</code> value in
a time zone that recognizes DST, this means that adding or subtracting
(say) <code class="literal">interval '1 day'</code> does not necessarily have the
same result as adding or subtracting <code class="literal">interval '24
hours'</code>.
For example, with the session time zone set
to <code class="literal">America/Denver</code>:
</p><pre class="screen">
SELECT timestamp with time zone '2005-04-02 12:00:00-07' + interval '1 day';
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2005-04-03 12:00:00-06</code>
SELECT timestamp with time zone '2005-04-02 12:00:00-07' + interval '24 hours';
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2005-04-03 13:00:00-06</code>
</pre><p>
This happens because an hour was skipped due to a change in daylight saving
time at <code class="literal">2005-04-03 02:00:00</code> in time zone
<code class="literal">America/Denver</code>.
</p><p>
Note there can be ambiguity in the <code class="literal">months</code> field returned by
<code class="function">age</code> because different months have different numbers of
days. <span class="productname">PostgreSQL</span>'s approach uses the month from the
earlier of the two dates when calculating partial months. For example,
<code class="literal">age('2004-06-01', '2004-04-30')</code> uses April to yield
<code class="literal">1 mon 1 day</code>, while using May would yield <code class="literal">1 mon 2
days</code> because May has 31 days, while April has only 30.
</p><p>
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 <code class="literal">EXTRACT(EPOCH FROM ...)</code>, then subtract the
results; this produces the
number of <span class="emphasis"><em>seconds</em></span> 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 <span class="quote">“<span class="quote"><code class="literal">-</code></span>”</span> operator
returns the number of days (24-hours) and hours/minutes/seconds
between the values, making the same adjustments. The <code class="function">age</code>
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 <code class="literal">timezone
= 'US/Eastern'</code>; there is a daylight saving time change between the
two dates used:
</p><pre class="screen">
SELECT EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">10537200.000000</code>
SELECT (EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00'))
/ 60 / 60 / 24;
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">121.9583333333333333</code>
SELECT timestamptz '2013-07-01 12:00:00' - timestamptz '2013-03-01 12:00:00';
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">121 days 23:00:00</code>
SELECT age(timestamptz '2013-07-01 12:00:00', timestamptz '2013-03-01 12:00:00');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">4 mons</code>
</pre><div class="sect2" id="FUNCTIONS-DATETIME-EXTRACT"><div class="titlepage"><div><div><h3 class="title">9.9.1. <code class="function">EXTRACT</code>, <code class="function">date_part</code> <a href="#FUNCTIONS-DATETIME-EXTRACT" class="id_link">#</a></h3></div></div></div><a id="id-1.5.8.15.13.2" class="indexterm"></a><a id="id-1.5.8.15.13.3" class="indexterm"></a><pre class="synopsis">
EXTRACT(<em class="replaceable"><code>field</code></em> FROM <em class="replaceable"><code>source</code></em>)
</pre><p>
The <code class="function">extract</code> function retrieves subfields
such as year or hour from date/time values.
<em class="replaceable"><code>source</code></em> must be a value expression of
type <code class="type">timestamp</code>, <code class="type">date</code>, <code class="type">time</code>,
or <code class="type">interval</code>. (Timestamps and times can be with or
without time zone.)
<em class="replaceable"><code>field</code></em> 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 <code class="type">date</code>, while
fields of a day or more cannot be extracted from a <code class="type">time</code>.
The <code class="function">extract</code> function returns values of type
<code class="type">numeric</code>.
</p><p>
The following are valid field names:
</p><div class="variablelist"><dl class="variablelist"><dt><span class="term"><code class="literal">century</code></span></dt><dd><p>
The century; for <code class="type">interval</code> values, the year field
divided by 100
</p><pre class="screen">
SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">20</code>
SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">21</code>
SELECT EXTRACT(CENTURY FROM DATE '0001-01-01 AD');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">1</code>
SELECT EXTRACT(CENTURY FROM DATE '0001-12-31 BC');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">-1</code>
SELECT EXTRACT(CENTURY FROM INTERVAL '2001 years');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">20</code>
</pre></dd><dt><span class="term"><code class="literal">day</code></span></dt><dd><p>
The day of the month (1–31); for <code class="type">interval</code>
values, the number of days
</p><pre class="screen">
SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">16</code>
SELECT EXTRACT(DAY FROM INTERVAL '40 days 1 minute');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">40</code>
</pre></dd><dt><span class="term"><code class="literal">decade</code></span></dt><dd><p>
The year field divided by 10
</p><pre class="screen">
SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">200</code>
</pre></dd><dt><span class="term"><code class="literal">dow</code></span></dt><dd><p>
The day of the week as Sunday (<code class="literal">0</code>) to
Saturday (<code class="literal">6</code>)
</p><pre class="screen">
SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">5</code>
</pre><p>
Note that <code class="function">extract</code>'s day of the week numbering
differs from that of the <code class="function">to_char(...,
'D')</code> function.
</p></dd><dt><span class="term"><code class="literal">doy</code></span></dt><dd><p>
The day of the year (1–365/366)
</p><pre class="screen">
SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">47</code>
</pre></dd><dt><span class="term"><code class="literal">epoch</code></span></dt><dd><p>
For <code class="type">timestamp with time zone</code> values, the
number of seconds since 1970-01-01 00:00:00 UTC (negative for
timestamps before that);
for <code class="type">date</code> and <code class="type">timestamp</code> values, the
nominal number of seconds since 1970-01-01 00:00:00,
without regard to timezone or daylight-savings rules;
for <code class="type">interval</code> values, the total number
of seconds in the interval
</p><pre class="screen">
SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">982384720.120000</code>
SELECT EXTRACT(EPOCH FROM TIMESTAMP '2001-02-16 20:38:40.12');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">982355920.120000</code>
SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">442800.000000</code>
</pre><p>
You can convert an epoch value back to a <code class="type">timestamp with time zone</code>
with <code class="function">to_timestamp</code>:
</p><pre class="screen">
SELECT to_timestamp(982384720.12);
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2001-02-17 04:38:40.12+00</code>
</pre><p>
Beware that applying <code class="function">to_timestamp</code> to an epoch
extracted from a <code class="type">date</code> or <code class="type">timestamp</code> 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.
</p></dd><dt><span class="term"><code class="literal">hour</code></span></dt><dd><p>
The hour field (0–23 in timestamps, unrestricted in
intervals)
</p><pre class="screen">
SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">20</code>
</pre></dd><dt><span class="term"><code class="literal">isodow</code></span></dt><dd><p>
The day of the week as Monday (<code class="literal">1</code>) to
Sunday (<code class="literal">7</code>)
</p><pre class="screen">
SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">7</code>
</pre><p>
This is identical to <code class="literal">dow</code> except for Sunday. This
matches the <acronym class="acronym">ISO</acronym> 8601 day of the week numbering.
</p></dd><dt><span class="term"><code class="literal">isoyear</code></span></dt><dd><p>
The <acronym class="acronym">ISO</acronym> 8601 week-numbering year that the date
falls in
</p><pre class="screen">
SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2005</code>
SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2006</code>
</pre><p>
Each <acronym class="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 class="acronym">ISO</acronym> year may be
different from the Gregorian year. See the <code class="literal">week</code>
field for more information.
</p></dd><dt><span class="term"><code class="literal">julian</code></span></dt><dd><p>
The <em class="firstterm">Julian Date</em> corresponding to the
date or timestamp. Timestamps
that are not local midnight result in a fractional value. See
<a class="xref" href="datetime-julian-dates.html" title="B.7. Julian Dates">Section B.7</a> for more information.
</p><pre class="screen">
SELECT EXTRACT(JULIAN FROM DATE '2006-01-01');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2453737</code>
SELECT EXTRACT(JULIAN FROM TIMESTAMP '2006-01-01 12:00');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2453737.50000000000000000000</code>
</pre></dd><dt><span class="term"><code class="literal">microseconds</code></span></dt><dd><p>
The seconds field, including fractional parts, multiplied by 1
000 000; note that this includes full seconds
</p><pre class="screen">
SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">28500000</code>
</pre></dd><dt><span class="term"><code class="literal">millennium</code></span></dt><dd><p>
The millennium; for <code class="type">interval</code> values, the year field
divided by 1000
</p><pre class="screen">
SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">3</code>
SELECT EXTRACT(MILLENNIUM FROM INTERVAL '2001 years');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2</code>
</pre><p>
Years in the 1900s are in the second millennium.
The third millennium started January 1, 2001.
</p></dd><dt><span class="term"><code class="literal">milliseconds</code></span></dt><dd><p>
The seconds field, including fractional parts, multiplied by
1000. Note that this includes full seconds.
</p><pre class="screen">
SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">28500.000</code>
</pre></dd><dt><span class="term"><code class="literal">minute</code></span></dt><dd><p>
The minutes field (0–59)
</p><pre class="screen">
SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">38</code>
</pre></dd><dt><span class="term"><code class="literal">month</code></span></dt><dd><p>
The number of the month within the year (1–12);
for <code class="type">interval</code> values, the number of months modulo 12
(0–11)
</p><pre class="screen">
SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2</code>
SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">3</code>
SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">1</code>
</pre></dd><dt><span class="term"><code class="literal">quarter</code></span></dt><dd><p>
The quarter of the year (1–4) that the date is in
</p><pre class="screen">
SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">1</code>
</pre></dd><dt><span class="term"><code class="literal">second</code></span></dt><dd><p>
The seconds field, including any fractional seconds
</p><pre class="screen">
SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">40.000000</code>
SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">28.500000</code>
</pre></dd><dt><span class="term"><code class="literal">timezone</code></span></dt><dd><p>
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,
<span class="productname">PostgreSQL</span> does not use UTC because
leap seconds are not handled.)
</p></dd><dt><span class="term"><code class="literal">timezone_hour</code></span></dt><dd><p>
The hour component of the time zone offset
</p></dd><dt><span class="term"><code class="literal">timezone_minute</code></span></dt><dd><p>
The minute component of the time zone offset
</p></dd><dt><span class="term"><code class="literal">week</code></span></dt><dd><p>
The number of the <acronym class="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.
</p><p>
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, <code class="literal">2005-01-01</code> is part of the 53rd week of year
2004, and <code class="literal">2006-01-01</code> is part of the 52nd week of year
2005, while <code class="literal">2012-12-31</code> is part of the first week of 2013.
It's recommended to use the <code class="literal">isoyear</code> field together with
<code class="literal">week</code> to get consistent results.
</p><pre class="screen">
SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">7</code>
</pre></dd><dt><span class="term"><code class="literal">year</code></span></dt><dd><p>
The year field. Keep in mind there is no <code class="literal">0 AD</code>, so subtracting
<code class="literal">BC</code> years from <code class="literal">AD</code> years should be done with care.
</p><pre class="screen">
SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2001</code>
</pre></dd></dl></div><p>
</p><p>
When processing an <code class="type">interval</code> value,
the <code class="function">extract</code> 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:
</p><pre class="screen">
SELECT INTERVAL '80 minutes';
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">01:20:00</code>
SELECT EXTRACT(MINUTES FROM INTERVAL '80 minutes');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">20</code>
</pre><p>
</p><div class="note"><h3 class="title">Note</h3><p>
When the input value is +/-Infinity, <code class="function">extract</code> returns
+/-Infinity for monotonically-increasing fields (<code class="literal">epoch</code>,
<code class="literal">julian</code>, <code class="literal">year</code>, <code class="literal">isoyear</code>,
<code class="literal">decade</code>, <code class="literal">century</code>, and <code class="literal">millennium</code>).
For other fields, NULL is returned. <span class="productname">PostgreSQL</span>
versions before 9.6 returned zero for all cases of infinite input.
</p></div><p>
The <code class="function">extract</code> function is primarily intended
for computational processing. For formatting date/time values for
display, see <a class="xref" href="functions-formatting.html" title="9.8. Data Type Formatting Functions">Section 9.8</a>.
</p><p>
The <code class="function">date_part</code> function is modeled on the traditional
<span class="productname">Ingres</span> equivalent to the
<acronym class="acronym">SQL</acronym>-standard function <code class="function">extract</code>:
</p><pre class="synopsis">
date_part('<em class="replaceable"><code>field</code></em>', <em class="replaceable"><code>source</code></em>)
</pre><p>
Note that here the <em class="replaceable"><code>field</code></em> parameter needs to
be a string value, not a name. The valid field names for
<code class="function">date_part</code> are the same as for
<code class="function">extract</code>.
For historical reasons, the <code class="function">date_part</code> function
returns values of type <code class="type">double precision</code>. This can result in
a loss of precision in certain uses. Using <code class="function">extract</code>
is recommended instead.
</p><pre class="screen">
SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">16</code>
SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">4</code>
</pre></div><div class="sect2" id="FUNCTIONS-DATETIME-TRUNC"><div class="titlepage"><div><div><h3 class="title">9.9.2. <code class="function">date_trunc</code> <a href="#FUNCTIONS-DATETIME-TRUNC" class="id_link">#</a></h3></div></div></div><a id="id-1.5.8.15.14.2" class="indexterm"></a><p>
The function <code class="function">date_trunc</code> is conceptually
similar to the <code class="function">trunc</code> function for numbers.
</p><p>
</p><pre class="synopsis">
date_trunc(<em class="replaceable"><code>field</code></em>, <em class="replaceable"><code>source</code></em> [, <em class="replaceable"><code>time_zone</code></em> ])
</pre><p>
<em class="replaceable"><code>source</code></em> is a value expression of type
<code class="type">timestamp</code>, <code class="type">timestamp with time zone</code>,
or <code class="type">interval</code>.
(Values of type <code class="type">date</code> and
<code class="type">time</code> are cast automatically to <code class="type">timestamp</code> or
<code class="type">interval</code>, respectively.)
<em class="replaceable"><code>field</code></em> selects to which precision to
truncate the input value. The return value is likewise of type
<code class="type">timestamp</code>, <code class="type">timestamp with time zone</code>,
or <code class="type">interval</code>,
and it has all fields that are less significant than the
selected one set to zero (or one, for day and month).
</p><p>
Valid values for <em class="replaceable"><code>field</code></em> are:
</p><table border="0" summary="Simple list" class="simplelist"><tr><td><code class="literal">microseconds</code></td></tr><tr><td><code class="literal">milliseconds</code></td></tr><tr><td><code class="literal">second</code></td></tr><tr><td><code class="literal">minute</code></td></tr><tr><td><code class="literal">hour</code></td></tr><tr><td><code class="literal">day</code></td></tr><tr><td><code class="literal">week</code></td></tr><tr><td><code class="literal">month</code></td></tr><tr><td><code class="literal">quarter</code></td></tr><tr><td><code class="literal">year</code></td></tr><tr><td><code class="literal">decade</code></td></tr><tr><td><code class="literal">century</code></td></tr><tr><td><code class="literal">millennium</code></td></tr></table><p>
</p><p>
When the input value is of type <code class="type">timestamp with time zone</code>,
the truncation is performed with respect to a particular time zone;
for example, truncation to <code class="literal">day</code> produces a value that
is midnight in that zone. By default, truncation is done with respect
to the current <a class="xref" href="runtime-config-client.html#GUC-TIMEZONE">TimeZone</a> setting, but the
optional <em class="replaceable"><code>time_zone</code></em> argument can be provided
to specify a different time zone. The time zone name can be specified
in any of the ways described in <a class="xref" href="datatype-datetime.html#DATATYPE-TIMEZONES" title="8.5.3. Time Zones">Section 8.5.3</a>.
</p><p>
A time zone cannot be specified when processing <code class="type">timestamp without
time zone</code> or <code class="type">interval</code> inputs. These are always
taken at face value.
</p><p>
Examples (assuming the local time zone is <code class="literal">America/New_York</code>):
</p><pre class="screen">
SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2001-02-16 20:00:00</code>
SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2001-01-01 00:00:00</code>
SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2001-02-16 00:00:00-05</code>
SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00', 'Australia/Sydney');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2001-02-16 08:00:00-05</code>
SELECT date_trunc('hour', INTERVAL '3 days 02:47:33');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">3 days 02:00:00</code>
</pre><p>
</p></div><div class="sect2" id="FUNCTIONS-DATETIME-BIN"><div class="titlepage"><div><div><h3 class="title">9.9.3. <code class="function">date_bin</code> <a href="#FUNCTIONS-DATETIME-BIN" class="id_link">#</a></h3></div></div></div><a id="id-1.5.8.15.15.2" class="indexterm"></a><p>
The function <code class="function">date_bin</code> <span class="quote">“<span class="quote">bins</span>”</span> the input
timestamp into the specified interval (the <em class="firstterm">stride</em>)
aligned with a specified origin.
</p><p>
</p><pre class="synopsis">
date_bin(<em class="replaceable"><code>stride</code></em>, <em class="replaceable"><code>source</code></em>, <em class="replaceable"><code>origin</code></em>)
</pre><p>
<em class="replaceable"><code>source</code></em> is a value expression of type
<code class="type">timestamp</code> or <code class="type">timestamp with time zone</code>. (Values
of type <code class="type">date</code> are cast automatically to
<code class="type">timestamp</code>.) <em class="replaceable"><code>stride</code></em> is a value
expression of type <code class="type">interval</code>. The return value is likewise
of type <code class="type">timestamp</code> or <code class="type">timestamp with time zone</code>,
and it marks the beginning of the bin into which the
<em class="replaceable"><code>source</code></em> is placed.
</p><p>
Examples:
</p><pre class="screen">
SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-01-01');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2020-02-11 15:30:00</code>
SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-01-01 00:02:30');
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2020-02-11 15:32:30</code>
</pre><p>
</p><p>
In the case of full units (1 minute, 1 hour, etc.), it gives the same result as
the analogous <code class="function">date_trunc</code> call, but the difference is
that <code class="function">date_bin</code> can truncate to an arbitrary interval.
</p><p>
The <em class="parameter"><code>stride</code></em> interval must be greater than zero and
cannot contain units of month or larger.
</p></div><div class="sect2" id="FUNCTIONS-DATETIME-ZONECONVERT"><div class="titlepage"><div><div><h3 class="title">9.9.4. <code class="literal">AT TIME ZONE</code> <a href="#FUNCTIONS-DATETIME-ZONECONVERT" class="id_link">#</a></h3></div></div></div><a id="id-1.5.8.15.16.2" class="indexterm"></a><a id="id-1.5.8.15.16.3" class="indexterm"></a><p>
The <code class="literal">AT TIME ZONE</code> operator converts time
stamp <span class="emphasis"><em>without</em></span> time zone to/from
time stamp <span class="emphasis"><em>with</em></span> time zone, and
<code class="type">time with time zone</code> values to different time
zones. <a class="xref" href="functions-datetime.html#FUNCTIONS-DATETIME-ZONECONVERT-TABLE" title="Table 9.34. AT TIME ZONE Variants">Table 9.34</a> shows its
variants.
</p><div class="table" id="FUNCTIONS-DATETIME-ZONECONVERT-TABLE"><p class="title"><strong>Table 9.34. <code class="literal">AT TIME ZONE</code> Variants</strong></p><div class="table-contents"><table class="table" summary="AT TIME ZONE Variants" border="1"><colgroup><col /></colgroup><thead><tr><th class="func_table_entry"><p class="func_signature">
Operator
</p>
<p>
Description
</p>
<p>
Example(s)
</p></th></tr></thead><tbody><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">timestamp without time zone</code> <code class="literal">AT TIME ZONE</code> <em class="replaceable"><code>zone</code></em>
→ <code class="returnvalue">timestamp with time zone</code>
</p>
<p>
Converts given time stamp <span class="emphasis"><em>without</em></span> time zone to
time stamp <span class="emphasis"><em>with</em></span> time zone, assuming the given
value is in the named time zone.
</p>
<p>
<code class="literal">timestamp '2001-02-16 20:38:40' at time zone 'America/Denver'</code>
→ <code class="returnvalue">2001-02-17 03:38:40+00</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">timestamp with time zone</code> <code class="literal">AT TIME ZONE</code> <em class="replaceable"><code>zone</code></em>
→ <code class="returnvalue">timestamp without time zone</code>
</p>
<p>
Converts given time stamp <span class="emphasis"><em>with</em></span> time zone to
time stamp <span class="emphasis"><em>without</em></span> time zone, as the time would
appear in that zone.
</p>
<p>
<code class="literal">timestamp with time zone '2001-02-16 20:38:40-05' at time zone 'America/Denver'</code>
→ <code class="returnvalue">2001-02-16 18:38:40</code>
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<code class="type">time with time zone</code> <code class="literal">AT TIME ZONE</code> <em class="replaceable"><code>zone</code></em>
→ <code class="returnvalue">time with time zone</code>
</p>
<p>
Converts given time <span class="emphasis"><em>with</em></span> time zone to a new time
zone. Since no date is supplied, this uses the currently active UTC
offset for the named destination zone.
</p>
<p>
<code class="literal">time with time zone '05:34:17-05' at time zone 'UTC'</code>
→ <code class="returnvalue">10:34:17+00</code>
</p></td></tr></tbody></table></div></div><br class="table-break" /><p>
In these expressions, the desired time zone <em class="replaceable"><code>zone</code></em> can be
specified either as a text value (e.g., <code class="literal">'America/Los_Angeles'</code>)
or as an interval (e.g., <code class="literal">INTERVAL '-08:00'</code>).
In the text case, a time zone name can be specified in any of the ways
described in <a class="xref" href="datatype-datetime.html#DATATYPE-TIMEZONES" title="8.5.3. Time Zones">Section 8.5.3</a>.
The interval case is only useful for zones that have fixed offsets from
UTC, so it is not very common in practice.
</p><p>
Examples (assuming the current <a class="xref" href="runtime-config-client.html#GUC-TIMEZONE">TimeZone</a> setting
is <code class="literal">America/Los_Angeles</code>):
</p><pre class="screen">
SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'America/Denver';
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2001-02-16 19:38:40-08</code>
SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'America/Denver';
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2001-02-16 18:38:40</code>
SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'Asia/Tokyo' AT TIME ZONE 'America/Chicago';
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2001-02-16 05:38:40</code>
</pre><p>
The first example adds a time zone to a value that lacks it, and
displays the value using the current <code class="varname">TimeZone</code>
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
<code class="varname">TimeZone</code> setting. The third example converts
Tokyo time to Chicago time.
</p><p>
The function <code class="literal"><code class="function">timezone</code>(<em class="replaceable"><code>zone</code></em>,
<em class="replaceable"><code>timestamp</code></em>)</code> is equivalent to the SQL-conforming construct
<code class="literal"><em class="replaceable"><code>timestamp</code></em> AT TIME ZONE
<em class="replaceable"><code>zone</code></em></code>.
</p></div><div class="sect2" id="FUNCTIONS-DATETIME-CURRENT"><div class="titlepage"><div><div><h3 class="title">9.9.5. Current Date/Time <a href="#FUNCTIONS-DATETIME-CURRENT" class="id_link">#</a></h3></div></div></div><a id="id-1.5.8.15.17.2" class="indexterm"></a><a id="id-1.5.8.15.17.3" class="indexterm"></a><p>
<span class="productname">PostgreSQL</span> 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:
</p><pre class="synopsis">
CURRENT_DATE
CURRENT_TIME
CURRENT_TIMESTAMP
CURRENT_TIME(<em class="replaceable"><code>precision</code></em>)
CURRENT_TIMESTAMP(<em class="replaceable"><code>precision</code></em>)
LOCALTIME
LOCALTIMESTAMP
LOCALTIME(<em class="replaceable"><code>precision</code></em>)
LOCALTIMESTAMP(<em class="replaceable"><code>precision</code></em>)
</pre><p>
</p><p>
<code class="function">CURRENT_TIME</code> and
<code class="function">CURRENT_TIMESTAMP</code> deliver values with time zone;
<code class="function">LOCALTIME</code> and
<code class="function">LOCALTIMESTAMP</code> deliver values without time zone.
</p><p>
<code class="function">CURRENT_TIME</code>,
<code class="function">CURRENT_TIMESTAMP</code>,
<code class="function">LOCALTIME</code>, and
<code class="function">LOCALTIMESTAMP</code>
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.
</p><p>
Some examples:
</p><pre class="screen">
SELECT CURRENT_TIME;
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">14:39:53.662522-05</code>
SELECT CURRENT_DATE;
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2019-12-23</code>
SELECT CURRENT_TIMESTAMP;
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2019-12-23 14:39:53.662522-05</code>
SELECT CURRENT_TIMESTAMP(2);
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2019-12-23 14:39:53.66-05</code>
SELECT LOCALTIMESTAMP;
<em class="lineannotation"><span class="lineannotation">Result: </span></em><code class="computeroutput">2019-12-23 14:39:53.662522</code>
</pre><p>
</p><p>
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 <span class="quote">“<span class="quote">current</span>”</span> time, so that multiple
modifications within the same transaction bear the same
time stamp.
</p><div class="note"><h3 class="title">Note</h3><p>
Other database systems might advance these values more
frequently.
</p></div><p>
<span class="productname">PostgreSQL</span> 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:
</p><pre class="synopsis">
transaction_timestamp()
statement_timestamp()
clock_timestamp()
timeofday()
now()
</pre><p>
</p><p>
<code class="function">transaction_timestamp()</code> is equivalent to
<code class="function">CURRENT_TIMESTAMP</code>, but is named to clearly reflect
what it returns.
<code class="function">statement_timestamp()</code> returns the start time of the current
statement (more specifically, the time of receipt of the latest command
message from the client).
<code class="function">statement_timestamp()</code> and <code class="function">transaction_timestamp()</code>
return the same value during the first command of a transaction, but might
differ during subsequent commands.
<code class="function">clock_timestamp()</code> returns the actual current time, and
therefore its value changes even within a single SQL command.
<code class="function">timeofday()</code> is a historical
<span class="productname">PostgreSQL</span> function. Like
<code class="function">clock_timestamp()</code>, it returns the actual current time,
but as a formatted <code class="type">text</code> string rather than a <code class="type">timestamp
with time zone</code> value.
<code class="function">now()</code> is a traditional <span class="productname">PostgreSQL</span>
equivalent to <code class="function">transaction_timestamp()</code>.
</p><p>
All the date/time data types also accept the special literal value
<code class="literal">now</code> to specify the current date and time (again,
interpreted as the transaction start time). Thus,
the following three all return the same result:
</p><pre class="programlisting">
SELECT CURRENT_TIMESTAMP;
SELECT now();
SELECT TIMESTAMP 'now'; -- but see tip below
</pre><p>
</p><div class="tip"><h3 class="title">Tip</h3><p>
Do not use the third form when specifying a value to be evaluated later,
for example in a <code class="literal">DEFAULT</code> clause for a table column.
The system will convert <code class="literal">now</code>
to a <code class="type">timestamp</code> 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 <a class="xref" href="datatype-datetime.html#DATATYPE-DATETIME-SPECIAL-VALUES" title="8.5.1.4. Special Values">Section 8.5.1.4</a>.)
</p></div></div><div class="sect2" id="FUNCTIONS-DATETIME-DELAY"><div class="titlepage"><div><div><h3 class="title">9.9.6. Delaying Execution <a href="#FUNCTIONS-DATETIME-DELAY" class="id_link">#</a></h3></div></div></div><a id="id-1.5.8.15.18.2" class="indexterm"></a><a id="id-1.5.8.15.18.3" class="indexterm"></a><a id="id-1.5.8.15.18.4" class="indexterm"></a><a id="id-1.5.8.15.18.5" class="indexterm"></a><a id="id-1.5.8.15.18.6" class="indexterm"></a><p>
The following functions are available to delay execution of the server
process:
</p><pre class="synopsis">
pg_sleep ( <code class="type">double precision</code> )
pg_sleep_for ( <code class="type">interval</code> )
pg_sleep_until ( <code class="type">timestamp with time zone</code> )
</pre><p>
<code class="function">pg_sleep</code> makes the current session's process
sleep until the given number of seconds have
elapsed. Fractional-second delays can be specified.
<code class="function">pg_sleep_for</code> is a convenience function to
allow the sleep time to be specified as an <code class="type">interval</code>.
<code class="function">pg_sleep_until</code> is a convenience function for when
a specific wake-up time is desired.
For example:
</p><pre class="programlisting">
SELECT pg_sleep(1.5);
SELECT pg_sleep_for('5 minutes');
SELECT pg_sleep_until('tomorrow 03:00');
</pre><p>
</p><div class="note"><h3 class="title">Note</h3><p>
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, <code class="function">pg_sleep_until</code> is not guaranteed to
wake up exactly at the specified time, but it will not wake up any earlier.
</p></div><div class="warning"><h3 class="title">Warning</h3><p>
Make sure that your session does not hold more locks than necessary
when calling <code class="function">pg_sleep</code> or its variants. Otherwise
other sessions might have to wait for your sleeping process, slowing down
the entire system.
</p></div></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="functions-formatting.html" title="9.8. Data Type Formatting Functions">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="functions.html" title="Chapter 9. Functions and Operators">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="functions-enum.html" title="9.10. Enum Support Functions">Next</a></td></tr><tr><td width="40%" align="left" valign="top">9.8. Data Type Formatting Functions </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 16.3 Documentation">Home</a></td><td width="40%" align="right" valign="top"> 9.10. Enum Support Functions</td></tr></table></div></body></html>
|