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
|
from tests.dialects.test_dialect import Validator
from sqlglot.helper import logger as helper_logger
class TestSQLite(Validator):
dialect = "sqlite"
def test_sqlite(self):
self.validate_identity("SELECT DATE()")
self.validate_identity("SELECT DATE('now', 'start of month', '+1 month', '-1 day')")
self.validate_identity("SELECT DATETIME(1092941466, 'unixepoch')")
self.validate_identity("SELECT DATETIME(1092941466, 'auto')")
self.validate_identity("SELECT DATETIME(1092941466, 'unixepoch', 'localtime')")
self.validate_identity("SELECT UNIXEPOCH()")
self.validate_identity("SELECT JULIANDAY('now') - JULIANDAY('1776-07-04')")
self.validate_identity("SELECT UNIXEPOCH() - UNIXEPOCH('2004-01-01 02:34:56')")
self.validate_identity("SELECT DATE('now', 'start of year', '+9 months', 'weekday 2')")
self.validate_identity("SELECT (JULIANDAY('now') - 2440587.5) * 86400.0")
self.validate_identity("SELECT UNIXEPOCH('now', 'subsec')")
self.validate_identity("SELECT TIMEDIFF('now', '1809-02-12')")
self.validate_identity(
"SELECT JSON_EXTRACT('[10, 20, [30, 40]]', '$[2]', '$[0]', '$[1]')",
)
self.validate_identity(
"""SELECT item AS "item", some AS "some" FROM data WHERE (item = 'value_1' COLLATE NOCASE) AND (some = 't' COLLATE NOCASE) ORDER BY item ASC LIMIT 1 OFFSET 0"""
)
self.validate_identity("SELECT * FROM GENERATE_SERIES(1, 5)")
self.validate_identity("SELECT INSTR(haystack, needle)")
self.validate_all("SELECT LIKE(y, x)", write={"sqlite": "SELECT x LIKE y"})
self.validate_all("SELECT GLOB('*y*', 'xyz')", write={"sqlite": "SELECT 'xyz' GLOB '*y*'"})
self.validate_all(
"SELECT LIKE('%y%', 'xyz', '')", write={"sqlite": "SELECT 'xyz' LIKE '%y%' ESCAPE ''"}
)
self.validate_all(
"CURRENT_DATE",
read={
"": "CURRENT_DATE",
"snowflake": "CURRENT_DATE()",
},
)
self.validate_all(
"CURRENT_TIME",
read={
"": "CURRENT_TIME",
"snowflake": "CURRENT_TIME()",
},
)
self.validate_all(
"CURRENT_TIMESTAMP",
read={
"": "CURRENT_TIMESTAMP",
"snowflake": "CURRENT_TIMESTAMP()",
},
)
self.validate_all(
"SELECT DATE('2020-01-01 16:03:05')",
read={
"snowflake": "SELECT CAST('2020-01-01 16:03:05' AS DATE)",
},
)
self.validate_all(
"SELECT CAST([a].[b] AS SMALLINT) FROM foo",
write={
"sqlite": 'SELECT CAST("a"."b" AS INTEGER) FROM foo',
"spark": "SELECT CAST(`a`.`b` AS SMALLINT) FROM foo",
},
)
self.validate_all(
"EDITDIST3(col1, col2)",
read={
"sqlite": "EDITDIST3(col1, col2)",
"spark": "LEVENSHTEIN(col1, col2)",
},
write={
"sqlite": "EDITDIST3(col1, col2)",
"spark": "LEVENSHTEIN(col1, col2)",
},
)
self.validate_all(
"SELECT fname, lname, age FROM person ORDER BY age DESC NULLS FIRST, fname ASC NULLS LAST, lname",
write={
"spark": "SELECT fname, lname, age FROM person ORDER BY age DESC NULLS FIRST, fname ASC NULLS LAST, lname",
"sqlite": "SELECT fname, lname, age FROM person ORDER BY age DESC NULLS FIRST, fname ASC NULLS LAST, lname",
},
)
self.validate_all("x", read={"snowflake": "LEAST(x)"})
self.validate_all("MIN(x)", read={"snowflake": "MIN(x)"}, write={"snowflake": "MIN(x)"})
self.validate_all(
"MIN(x, y, z)",
read={"snowflake": "LEAST(x, y, z)"},
write={"snowflake": "LEAST(x, y, z)"},
)
self.validate_identity(
"SELECT * FROM station WHERE city IS NOT ''",
"SELECT * FROM station WHERE NOT city IS ''",
)
def test_strftime(self):
self.validate_identity("SELECT STRFTIME('%Y/%m/%d', 'now')")
self.validate_identity("SELECT STRFTIME('%Y-%m-%d', '2016-10-16', 'start of month')")
self.validate_identity(
"SELECT STRFTIME('%s')",
"SELECT STRFTIME('%s', CURRENT_TIMESTAMP)",
)
self.validate_all(
"SELECT STRFTIME('%Y-%m-%d', '2020-01-01 12:05:03')",
write={
"duckdb": "SELECT STRFTIME(CAST('2020-01-01 12:05:03' AS TIMESTAMP), '%Y-%m-%d')",
"sqlite": "SELECT STRFTIME('%Y-%m-%d', '2020-01-01 12:05:03')",
},
)
self.validate_all(
"SELECT STRFTIME('%Y-%m-%d', CURRENT_TIMESTAMP)",
write={
"duckdb": "SELECT STRFTIME(CAST(CURRENT_TIMESTAMP AS TIMESTAMP), '%Y-%m-%d')",
"sqlite": "SELECT STRFTIME('%Y-%m-%d', CURRENT_TIMESTAMP)",
},
)
def test_datediff(self):
self.validate_all(
"DATEDIFF(a, b, 'day')",
write={"sqlite": "CAST((JULIANDAY(a) - JULIANDAY(b)) AS INTEGER)"},
)
self.validate_all(
"DATEDIFF(a, b, 'hour')",
write={"sqlite": "CAST((JULIANDAY(a) - JULIANDAY(b)) * 24.0 AS INTEGER)"},
)
self.validate_all(
"DATEDIFF(a, b, 'year')",
write={"sqlite": "CAST((JULIANDAY(a) - JULIANDAY(b)) / 365.0 AS INTEGER)"},
)
def test_hexadecimal_literal(self):
self.validate_all(
"SELECT 0XCC",
write={
"sqlite": "SELECT x'CC'",
"mysql": "SELECT x'CC'",
},
)
def test_window_null_treatment(self):
self.validate_all(
"SELECT FIRST_VALUE(Name) OVER (PARTITION BY AlbumId ORDER BY Bytes DESC) AS LargestTrack FROM tracks",
write={
"sqlite": "SELECT FIRST_VALUE(Name) OVER (PARTITION BY AlbumId ORDER BY Bytes DESC) AS LargestTrack FROM tracks"
},
)
def test_longvarchar_dtype(self):
self.validate_all(
"CREATE TABLE foo (bar LONGVARCHAR)",
write={"sqlite": "CREATE TABLE foo (bar TEXT)"},
)
def test_warnings(self):
with self.assertLogs(helper_logger) as cm:
self.validate_identity(
"SELECT * FROM t AS t(c1, c2)",
"SELECT * FROM t AS t",
)
self.assertIn("Named columns are not supported in table alias.", cm.output[0])
def test_ddl(self):
for conflict_action in ("ABORT", "FAIL", "IGNORE", "REPLACE", "ROLLBACK"):
with self.subTest(f"ON CONFLICT {conflict_action}"):
self.validate_identity("CREATE TABLE a (b, c, UNIQUE (b, c) ON CONFLICT IGNORE)")
self.validate_identity("INSERT OR ABORT INTO foo (x, y) VALUES (1, 2)")
self.validate_identity("INSERT OR FAIL INTO foo (x, y) VALUES (1, 2)")
self.validate_identity("INSERT OR IGNORE INTO foo (x, y) VALUES (1, 2)")
self.validate_identity("INSERT OR REPLACE INTO foo (x, y) VALUES (1, 2)")
self.validate_identity("INSERT OR ROLLBACK INTO foo (x, y) VALUES (1, 2)")
self.validate_identity("CREATE TABLE foo (id INTEGER PRIMARY KEY ASC)")
self.validate_identity("CREATE TEMPORARY TABLE foo (id INTEGER)")
self.validate_all(
"""
CREATE TABLE "Track"
(
CONSTRAINT "PK_Track" FOREIGN KEY ("TrackId"),
FOREIGN KEY ("AlbumId") REFERENCES "Album" (
"AlbumId"
) ON DELETE NO ACTION ON UPDATE NO ACTION,
FOREIGN KEY ("AlbumId") ON DELETE CASCADE ON UPDATE RESTRICT,
FOREIGN KEY ("AlbumId") ON DELETE SET NULL ON UPDATE SET DEFAULT
)
""",
write={
"sqlite": """CREATE TABLE "Track" (
CONSTRAINT "PK_Track" FOREIGN KEY ("TrackId"),
FOREIGN KEY ("AlbumId") REFERENCES "Album" (
"AlbumId"
) ON DELETE NO ACTION ON UPDATE NO ACTION,
FOREIGN KEY ("AlbumId") ON DELETE CASCADE ON UPDATE RESTRICT,
FOREIGN KEY ("AlbumId") ON DELETE SET NULL ON UPDATE SET DEFAULT
)""",
},
pretty=True,
)
self.validate_all(
"CREATE TABLE z (a INTEGER UNIQUE PRIMARY KEY AUTOINCREMENT)",
read={
"mysql": "CREATE TABLE z (a INT UNIQUE PRIMARY KEY AUTO_INCREMENT)",
"postgres": "CREATE TABLE z (a INT GENERATED BY DEFAULT AS IDENTITY NOT NULL UNIQUE PRIMARY KEY)",
},
write={
"sqlite": "CREATE TABLE z (a INTEGER UNIQUE PRIMARY KEY AUTOINCREMENT)",
"mysql": "CREATE TABLE z (a INT UNIQUE PRIMARY KEY AUTO_INCREMENT)",
"postgres": "CREATE TABLE z (a INT GENERATED BY DEFAULT AS IDENTITY NOT NULL UNIQUE PRIMARY KEY)",
},
)
self.validate_all(
"""CREATE TABLE "x" ("Name" NVARCHAR(200) NOT NULL)""",
write={
"sqlite": """CREATE TABLE "x" ("Name" TEXT(200) NOT NULL)""",
"mysql": "CREATE TABLE `x` (`Name` VARCHAR(200) NOT NULL)",
},
)
|