xref: /sqlite-3.40.0/test/date3.test (revision 4b51e8bd)
1*4b51e8bdSdrh# 2022-01-27
2*4b51e8bdSdrh#
3*4b51e8bdSdrh# The author disclaims copyright to this source code.  In place of
4*4b51e8bdSdrh# a legal notice, here is a blessing:
5*4b51e8bdSdrh#
6*4b51e8bdSdrh#    May you do good and not evil.
7*4b51e8bdSdrh#    May you find forgiveness for yourself and forgive others.
8*4b51e8bdSdrh#    May you share freely, never taking more than you give.
9*4b51e8bdSdrh#
10*4b51e8bdSdrh#***********************************************************************
11*4b51e8bdSdrh# This file implements regression tests for SQLite library.  The
12*4b51e8bdSdrh# focus of this file is testing date and time functions.
13*4b51e8bdSdrh#
14*4b51e8bdSdrh
15*4b51e8bdSdrhset testdir [file dirname $argv0]
16*4b51e8bdSdrhsource $testdir/tester.tcl
17*4b51e8bdSdrh
18*4b51e8bdSdrh# Skip this whole file if date and time functions are omitted
19*4b51e8bdSdrh# at compile-time
20*4b51e8bdSdrh#
21*4b51e8bdSdrhifcapable {!datetime} {
22*4b51e8bdSdrh  finish_test
23*4b51e8bdSdrh  return
24*4b51e8bdSdrh}
25*4b51e8bdSdrh
26*4b51e8bdSdrhproc datetest {tnum expr result} {
27*4b51e8bdSdrh  do_test date3-$tnum [subst {
28*4b51e8bdSdrh    execsql "SELECT coalesce($expr,'NULL')"
29*4b51e8bdSdrh  }] [list $result]
30*4b51e8bdSdrh}
31*4b51e8bdSdrhset tcl_precision 15
32*4b51e8bdSdrh
33*4b51e8bdSdrh# EVIDENCE-OF: R-45708-63005 unixepoch(time-value, modifier, modifier,
34*4b51e8bdSdrh# ...)
35*4b51e8bdSdrh#
36*4b51e8bdSdrhdatetest 1.1 {unixepoch('1970-01-01')} {0}
37*4b51e8bdSdrhdatetest 1.2 {unixepoch('1969-12-31 23:59:59')} {-1}
38*4b51e8bdSdrhdatetest 1.3 {unixepoch('2106-02-07 06:28:15')} {4294967295}
39*4b51e8bdSdrhdatetest 1.4 {unixepoch('2106-02-07 06:28:16')} {4294967296}
40*4b51e8bdSdrhdatetest 1.5 {unixepoch('9999-12-31 23:59:59')} {253402300799}
41*4b51e8bdSdrhdatetest 1.6 {unixepoch('0000-01-01 00:00:00')} {-62167219200}
42*4b51e8bdSdrh
43*4b51e8bdSdrh# EVIDENCE-OF: R-30877-63179 The unixepoch() function returns a unix
44*4b51e8bdSdrh# timestamp - the number of seconds since 1970-01-01 00:00:00 UTC.
45*4b51e8bdSdrh#
46*4b51e8bdSdrhfor {set i 1} {$i<=100} {incr i} {
47*4b51e8bdSdrh  set x [expr {int(rand()*0xfffffffff)-0xffffffff}]
48*4b51e8bdSdrh  datetest 1.7.$i "unixepoch($x,'unixepoch')==$x" {1}
49*4b51e8bdSdrh}
50*4b51e8bdSdrh
51*4b51e8bdSdrh# EVIDENCE-OF: R-62992-54137 The unixepoch() always returns an integer,
52*4b51e8bdSdrh# even if the input time-value has millisecond precision.
53*4b51e8bdSdrh#
54*4b51e8bdSdrhdatetest 1.8 {unixepoch('2022-01-27 12:59:28.052')} {1643288368}
55*4b51e8bdSdrh
56*4b51e8bdSdrh# EVIDENCE-OF: R-05412-24332 If the time-value is numeric (the
57*4b51e8bdSdrh# DDDDDDDDDD format) then the 'auto' modifier causes the time-value to
58*4b51e8bdSdrh# interpreted as either a julian day number or a unix timestamp,
59*4b51e8bdSdrh# depending on its magnitude.
60*4b51e8bdSdrh#
61*4b51e8bdSdrh# EVIDENCE-OF: R-56763-40111 If the value is between 0.0 and
62*4b51e8bdSdrh# 5373484.499999, then it is interpreted as a julian day number
63*4b51e8bdSdrh# (corresponding to dates between -4713-11-24 12:00:00 and 9999-12-31
64*4b51e8bdSdrh# 23:59:59, inclusive).
65*4b51e8bdSdrh#
66*4b51e8bdSdrh# EVIDENCE-OF: R-07289-49223 For numeric values outside of the range of
67*4b51e8bdSdrh# valid julian day numbers, but within the range of -210866760000 to
68*4b51e8bdSdrh# 253402300799, the 'auto' modifier causes the value to be interpreted
69*4b51e8bdSdrh# as a unix timestamp.
70*4b51e8bdSdrh#
71*4b51e8bdSdrh# EVIDENCE-OF: R-20795-34947 Other numeric values are out of range and
72*4b51e8bdSdrh# cause a NULL return.
73*4b51e8bdSdrh#
74*4b51e8bdSdrhforeach {tn jd date} {
75*4b51e8bdSdrh  2.1  0.0              {-4713-11-24 12:00:00}
76*4b51e8bdSdrh  2.2  5373484.4999999  {9999-12-31 23:59:59}
77*4b51e8bdSdrh  2.3  2440587.5        {1970-01-01 00:00:00}
78*4b51e8bdSdrh  2.4  2440587.49998843 {1969-12-31 23:59:59}
79*4b51e8bdSdrh  2.5  2440615.7475463  {1970-01-29 05:56:28}
80*4b51e8bdSdrh
81*4b51e8bdSdrh  2.10 -1               {1969-12-31 23:59:59}
82*4b51e8bdSdrh  2.11 5373485          {1970-03-04 04:38:05}
83*4b51e8bdSdrh  2.12 -210866760000    {-4713-11-24 12:00:00}
84*4b51e8bdSdrh  2.13 253402300799     {9999-12-31 23:59:59}
85*4b51e8bdSdrh
86*4b51e8bdSdrh  2.20 -210866760001    {NULL}
87*4b51e8bdSdrh  2.21 253402300800     {NULL}
88*4b51e8bdSdrh} {
89*4b51e8bdSdrh  datetest $tn "datetime($jd,'auto')" $date
90*4b51e8bdSdrh}
91*4b51e8bdSdrh
92*4b51e8bdSdrh# EVIDENCE-OF: R-38886-35357 The 'auto' modifier is a no-op for text
93*4b51e8bdSdrh# time-values.
94*4b51e8bdSdrh#
95*4b51e8bdSdrhdatetest 2.30 {date('2022-01-29','auto')==date('2022-01-29')} {1}
96*4b51e8bdSdrh
97*4b51e8bdSdrh# EVIDENCE-OF: R-53132-26856 The 'auto' modifier can be used to work
98*4b51e8bdSdrh# with date/time values even in cases where it is not known if the
99*4b51e8bdSdrh# julian day number or unix timestamp formats are in use.
100*4b51e8bdSdrh#
101*4b51e8bdSdrhdo_execsql_test date3-2.40 {
102*4b51e8bdSdrh  WITH tx(timeval,datetime) AS (
103*4b51e8bdSdrh     VALUES('2022-01-27 13:15:44','2022-01-27 13:15:44'),
104*4b51e8bdSdrh           (2459607.05260275,'2022-01-27 13:15:44'),
105*4b51e8bdSdrh           (1643289344,'2022-01-27 13:15:44')
106*4b51e8bdSdrh  )
107*4b51e8bdSdrh  SELECT datetime(timeval,'auto') == datetime FROM tx;
108*4b51e8bdSdrh} {1 1 1}
109*4b51e8bdSdrh
110*4b51e8bdSdrh# EVIDENCE-OF: R-49255-55373 The "unixepoch" modifier (11) only works if
111*4b51e8bdSdrh# it immediately follows a time value in the DDDDDDDDDD format.
112*4b51e8bdSdrh#
113*4b51e8bdSdrh# EVIDENCE-OF: R-23075-39245 This modifier causes the DDDDDDDDDD to be
114*4b51e8bdSdrh# interpreted not as a Julian day number as it normally would be, but as
115*4b51e8bdSdrh# Unix Time - the number of seconds since 1970.
116*4b51e8bdSdrh#
117*4b51e8bdSdrhdatetest 3.1 {datetime(2459607.05,'+1 hour','unixepoch')} {NULL}
118*4b51e8bdSdrhdatetest 3.2 {datetime(2459607.05,'unixepoch','+1 hour')} {1970-01-29 12:13:27}
119*4b51e8bdSdrh
120*4b51e8bdSdrh# EVIDENCE-OF: R-21150-52363 The "julianday" modifier must immediately
121*4b51e8bdSdrh# follow the initial time-value which must be of the form DDDDDDDDD.
122*4b51e8bdSdrh#
123*4b51e8bdSdrh# EVIDENCE-OF: R-31176-64601 Any other use of the 'julianday' modifier
124*4b51e8bdSdrh# is an error and causes the function to return NULL.
125*4b51e8bdSdrh#
126*4b51e8bdSdrh# EVIDENCE-OF: R-32483-36353 The 'julianday' modifier forces the
127*4b51e8bdSdrh# time-value number to be interpreted as a julian-day number.
128*4b51e8bdSdrh#
129*4b51e8bdSdrh# EVIDENCE-OF: R-25859-20124 The only difference is that adding
130*4b51e8bdSdrh# 'julianday' forces the DDDDDDDDD time-value format, and causes a NULL
131*4b51e8bdSdrh# to be returned if any other time-value format is used.
132*4b51e8bdSdrh#
133*4b51e8bdSdrhdatetest 4.1 {datetime(2459607,'julianday')}           {2022-01-27 12:00:00}
134*4b51e8bdSdrhdatetest 4.2 {datetime(2459607,'+1 hour','julianday')} {NULL}
135*4b51e8bdSdrhdatetest 4.3 {datetime('2022-01-27','julianday')}      {NULL}
136*4b51e8bdSdrh
137*4b51e8bdSdrh
138*4b51e8bdSdrh
139*4b51e8bdSdrh# EVIDENCE-OF: R-33431-18865 Unix timestamps for the first 63 days of
140*4b51e8bdSdrh# 1970 will be interpreted as julian day numbers.
141*4b51e8bdSdrh#
142*4b51e8bdSdrhdo_execsql_test date3-5.0 {
143*4b51e8bdSdrh  WITH inc(x) AS (VALUES(-10) UNION ALL SELECT x+1 FROM inc WHERE x<100)
144*4b51e8bdSdrh  SELECT count(*) FROM inc
145*4b51e8bdSdrh  WHERE datetime('1970-01-01',format('%+d days',x))
146*4b51e8bdSdrh     <> datetime(unixepoch('1970-01-01',format('%+d days',x)),'auto');
147*4b51e8bdSdrh} {63}
148*4b51e8bdSdrh
149*4b51e8bdSdrhfinish_test
150