Skip to content

Commit

Permalink
Feat: improve transpilation of CREATE TABLE LIKE statement (#2923)
Browse files Browse the repository at this point in the history
* Feat(duckdb): immitate CREATE TABLE a LIKE b statement

* Improve transpilation with flags

* PR feedback
  • Loading branch information
georgesittas committed Feb 6, 2024
1 parent 15582f4 commit 838e780
Show file tree
Hide file tree
Showing 13 changed files with 99 additions and 29 deletions.
3 changes: 3 additions & 0 deletions sqlglot/dialects/clickhouse.py
Original file line number Diff line number Diff line change
Expand Up @@ -614,6 +614,9 @@ class Generator(generator.Generator):
"NAMED COLLECTION",
}

def likeproperty_sql(self, expression: exp.LikeProperty) -> str:
return f"AS {self.sql(expression, 'this')}"

def _any_to_has(
self,
expression: exp.EQ | exp.NEQ,
Expand Down
5 changes: 0 additions & 5 deletions sqlglot/dialects/dialect.py
Original file line number Diff line number Diff line change
Expand Up @@ -569,11 +569,6 @@ def no_trycast_sql(self: Generator, expression: exp.TryCast) -> str:
return self.cast_sql(expression)


def no_properties_sql(self: Generator, expression: exp.Properties) -> str:
self.unsupported("Properties unsupported")
return ""


def no_comment_column_constraint_sql(
self: Generator, expression: exp.CommentColumnConstraint
) -> str:
Expand Down
1 change: 1 addition & 0 deletions sqlglot/dialects/drill.py
Original file line number Diff line number Diff line change
Expand Up @@ -99,6 +99,7 @@ class Generator(generator.Generator):
QUERY_HINTS = False
NVL2_SUPPORTED = False
LAST_DAY_SUPPORTS_DATE_PART = False
SUPPORTS_CREATE_TABLE_LIKE = False

TYPE_MAPPING = {
**generator.Generator.TYPE_MAPPING,
Expand Down
14 changes: 10 additions & 4 deletions sqlglot/dialects/duckdb.py
Original file line number Diff line number Diff line change
Expand Up @@ -17,7 +17,6 @@
format_time_lambda,
inline_array_sql,
no_comment_column_constraint_sql,
no_properties_sql,
no_safe_divide_sql,
no_timestamp_sql,
pivot_column_names,
Expand Down Expand Up @@ -333,6 +332,7 @@ class Generator(generator.Generator):
JSON_KEY_VALUE_PAIR_SEP = ","
IGNORE_NULLS_IN_FUNC = True
JSON_PATH_BRACKETED_KEY_SUPPORTED = False
SUPPORTS_CREATE_TABLE_LIKE = False

TRANSFORMS = {
**generator.Generator.TRANSFORMS,
Expand Down Expand Up @@ -391,7 +391,6 @@ class Generator(generator.Generator):
# DuckDB doesn't allow qualified columns inside of PIVOT expressions.
# See: https://github.com/duckdb/duckdb/blob/671faf92411182f81dce42ac43de8bfb05d9909e/src/planner/binder/tableref/bind_pivot.cpp#L61-L62
exp.Pivot: transforms.preprocess([transforms.unqualify_columns]),
exp.Properties: no_properties_sql,
exp.RegexpExtract: regexp_extract_sql,
exp.RegexpReplace: lambda self, e: self.func(
"REGEXP_REPLACE",
Expand Down Expand Up @@ -467,11 +466,18 @@ class Generator(generator.Generator):

UNWRAPPED_INTERVAL_VALUES = (exp.Column, exp.Literal, exp.Paren)

# DuckDB doesn't generally support CREATE TABLE .. properties
# https://duckdb.org/docs/sql/statements/create_table.html
PROPERTIES_LOCATION = {
**generator.Generator.PROPERTIES_LOCATION,
exp.VolatileProperty: exp.Properties.Location.UNSUPPORTED,
prop: exp.Properties.Location.UNSUPPORTED
for prop in generator.Generator.PROPERTIES_LOCATION
}

# There are a few exceptions (e.g. temporary tables) which are supported or
# can be transpiled to DuckDB, so we explicitly override them accordingly
PROPERTIES_LOCATION[exp.LikeProperty] = exp.Properties.Location.POST_SCHEMA
PROPERTIES_LOCATION[exp.TemporaryProperty] = exp.Properties.Location.POST_CREATE

def timefromparts_sql(self, expression: exp.TimeFromParts) -> str:
nano = expression.args.get("nano")
if nano is not None:
Expand Down
1 change: 1 addition & 0 deletions sqlglot/dialects/postgres.py
Original file line number Diff line number Diff line change
Expand Up @@ -393,6 +393,7 @@ class Generator(generator.Generator):
SUPPORTS_SELECT_INTO = True
JSON_TYPE_REQUIRED_FOR_EXTRACTION = True
SUPPORTS_UNLOGGED_TABLES = True
LIKE_PROPERTY_INSIDE_SCHEMA = True

SUPPORTED_JSON_PATH_PARTS = {
exp.JSONPathKey,
Expand Down
1 change: 1 addition & 0 deletions sqlglot/dialects/presto.py
Original file line number Diff line number Diff line change
Expand Up @@ -291,6 +291,7 @@ class Generator(generator.Generator):
STRUCT_DELIMITER = ("(", ")")
LIMIT_ONLY_LITERALS = True
SUPPORTS_SINGLE_ARG_CONCAT = False
LIKE_PROPERTY_INSIDE_SCHEMA = True

PROPERTIES_LOCATION = {
**generator.Generator.PROPERTIES_LOCATION,
Expand Down
5 changes: 0 additions & 5 deletions sqlglot/dialects/redshift.py
Original file line number Diff line number Diff line change
Expand Up @@ -195,11 +195,6 @@ class Generator(Postgres.Generator):
exp.DataType.Type.VARBINARY: "VARBYTE",
}

PROPERTIES_LOCATION = {
**Postgres.Generator.PROPERTIES_LOCATION,
exp.LikeProperty: exp.Properties.Location.POST_WITH,
}

TRANSFORMS = {
**Postgres.Generator.TRANSFORMS,
exp.Concat: concat_to_dpipe_sql,
Expand Down
12 changes: 10 additions & 2 deletions sqlglot/dialects/sqlite.py
Original file line number Diff line number Diff line change
Expand Up @@ -91,6 +91,7 @@ class Generator(generator.Generator):
QUERY_HINTS = False
NVL2_SUPPORTED = False
JSON_PATH_BRACKETED_KEY_SUPPORTED = False
SUPPORTS_CREATE_TABLE_LIKE = False

SUPPORTED_JSON_PATH_PARTS = {
exp.JSONPathKey,
Expand Down Expand Up @@ -151,11 +152,18 @@ class Generator(generator.Generator):
exp.TryCast: no_trycast_sql,
}

# SQLite doesn't generally support CREATE TABLE .. properties
# https://www.sqlite.org/lang_createtable.html
PROPERTIES_LOCATION = {
k: exp.Properties.Location.UNSUPPORTED
for k, v in generator.Generator.PROPERTIES_LOCATION.items()
prop: exp.Properties.Location.UNSUPPORTED
for prop in generator.Generator.PROPERTIES_LOCATION
}

# There are a few exceptions (e.g. temporary tables) which are supported or
# can be transpiled to SQLite, so we explicitly override them accordingly
PROPERTIES_LOCATION[exp.LikeProperty] = exp.Properties.Location.POST_SCHEMA
PROPERTIES_LOCATION[exp.TemporaryProperty] = exp.Properties.Location.POST_CREATE

LIMIT_FETCH = "LIMIT"

def cast_sql(self, expression: exp.Cast, safe_prefix: t.Optional[str] = None) -> str:
Expand Down
15 changes: 12 additions & 3 deletions sqlglot/dialects/tsql.py
Original file line number Diff line number Diff line change
Expand Up @@ -860,22 +860,31 @@ def create_sql(self, expression: exp.Create) -> str:
exists = expression.args.pop("exists", None)
sql = super().create_sql(expression)

like_property = expression.find(exp.LikeProperty)
if like_property:
ctas_expression = like_property.this
else:
ctas_expression = expression.expression

table = expression.find(exp.Table)

# Convert CTAS statement to SELECT .. INTO ..
if kind == "TABLE" and expression.expression:
ctas_with = expression.expression.args.get("with")
if kind == "TABLE" and ctas_expression:
ctas_with = ctas_expression.args.get("with")
if ctas_with:
ctas_with = ctas_with.pop()

subquery = expression.expression
subquery = ctas_expression
if isinstance(subquery, exp.Subqueryable):
subquery = subquery.subquery()

select_into = exp.select("*").from_(exp.alias_(subquery, "temp", table=True))
select_into.set("into", exp.Into(this=table))
select_into.set("with", ctas_with)

if like_property:
select_into.limit(0, copy=False)

sql = self.sql(select_into)

if exists:
Expand Down
24 changes: 21 additions & 3 deletions sqlglot/generator.py
Original file line number Diff line number Diff line change
Expand Up @@ -290,6 +290,12 @@ class Generator(metaclass=_Generator):
# Whether or not UNLOGGED tables can be created
SUPPORTS_UNLOGGED_TABLES = False

# Whether or not the CREATE TABLE LIKE statement is supported
SUPPORTS_CREATE_TABLE_LIKE = True

# Whether or not the LikeProperty needs to be specified inside of the schema clause
LIKE_PROPERTY_INSIDE_SCHEMA = False

# Whether or not the JSON extraction operators expect a value of type JSON
JSON_TYPE_REQUIRED_FOR_EXTRACTION = False

Expand Down Expand Up @@ -1252,9 +1258,21 @@ def property_sql(self, expression: exp.Property) -> str:
return f"{property_name}={self.sql(expression, 'this')}"

def likeproperty_sql(self, expression: exp.LikeProperty) -> str:
options = " ".join(f"{e.name} {self.sql(e, 'value')}" for e in expression.expressions)
options = f" {options}" if options else ""
return f"LIKE {self.sql(expression, 'this')}{options}"
if self.SUPPORTS_CREATE_TABLE_LIKE:
options = " ".join(f"{e.name} {self.sql(e, 'value')}" for e in expression.expressions)
options = f" {options}" if options else ""

like = f"LIKE {self.sql(expression, 'this')}{options}"
if self.LIKE_PROPERTY_INSIDE_SCHEMA and not isinstance(expression.parent, exp.Schema):
like = f"({like})"

return like

if expression.expressions:
self.unsupported("Transpilation of LIKE property options is unsupported")

select = exp.select("*").from_(expression.this).limit(0)
return f"AS {self.sql(select)}"

def fallbackproperty_sql(self, expression: exp.FallbackProperty) -> str:
no = "NO " if expression.args.get("no") else ""
Expand Down
25 changes: 25 additions & 0 deletions tests/dialects/test_dialect.py
Original file line number Diff line number Diff line change
Expand Up @@ -378,6 +378,31 @@ def test_cast(self):
read={"postgres": "INET '127.0.0.1/32'"},
)

def test_ddl(self):
self.validate_all(
"CREATE TABLE a LIKE b",
write={
"": "CREATE TABLE a LIKE b",
"bigquery": "CREATE TABLE a LIKE b",
"clickhouse": "CREATE TABLE a AS b",
"databricks": "CREATE TABLE a LIKE b",
"doris": "CREATE TABLE a LIKE b",
"drill": "CREATE TABLE a AS SELECT * FROM b LIMIT 0",
"duckdb": "CREATE TABLE a AS SELECT * FROM b LIMIT 0",
"hive": "CREATE TABLE a LIKE b",
"mysql": "CREATE TABLE a LIKE b",
"oracle": "CREATE TABLE a LIKE b",
"postgres": "CREATE TABLE a (LIKE b)",
"presto": "CREATE TABLE a (LIKE b)",
"redshift": "CREATE TABLE a (LIKE b)",
"snowflake": "CREATE TABLE a LIKE b",
"spark": "CREATE TABLE a LIKE b",
"sqlite": "CREATE TABLE a AS SELECT * FROM b LIMIT 0",
"trino": "CREATE TABLE a (LIKE b)",
"tsql": "SELECT TOP 0 * INTO a FROM b AS temp",
},
)

def test_heredoc_strings(self):
for dialect in ("clickhouse", "postgres", "redshift"):
# Invalid matching tag
Expand Down
16 changes: 13 additions & 3 deletions tests/dialects/test_redshift.py
Original file line number Diff line number Diff line change
Expand Up @@ -481,16 +481,26 @@ def test_values(self):
)

def test_create_table_like(self):
self.validate_identity(
"CREATE TABLE SOUP (LIKE other_table) DISTKEY(soup1) SORTKEY(soup2) DISTSTYLE ALL"
)

self.validate_all(
"CREATE TABLE t1 LIKE t2",
"CREATE TABLE t1 (LIKE t2)",
write={
"postgres": "CREATE TABLE t1 (LIKE t2)",
"presto": "CREATE TABLE t1 (LIKE t2)",
"redshift": "CREATE TABLE t1 (LIKE t2)",
"trino": "CREATE TABLE t1 (LIKE t2)",
},
)
self.validate_all(
"CREATE TABLE SOUP (LIKE other_table) DISTKEY(soup1) SORTKEY(soup2) DISTSTYLE ALL",
"CREATE TABLE t1 (col VARCHAR, LIKE t2)",
write={
"redshift": "CREATE TABLE SOUP (LIKE other_table) DISTKEY(soup1) SORTKEY(soup2) DISTSTYLE ALL",
"postgres": "CREATE TABLE t1 (col VARCHAR, LIKE t2)",
"presto": "CREATE TABLE t1 (col VARCHAR, LIKE t2)",
"redshift": "CREATE TABLE t1 (col VARCHAR, LIKE t2)",
"trino": "CREATE TABLE t1 (col VARCHAR, LIKE t2)",
},
)

Expand Down
6 changes: 2 additions & 4 deletions tests/dialects/test_sqlite.py
Original file line number Diff line number Diff line change
Expand Up @@ -10,11 +10,9 @@ def test_ddl(self):
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 foo (id INTEGER PRIMARY KEY ASC)",
write={"sqlite": "CREATE TABLE foo (id INTEGER PRIMARY KEY ASC)"},
)
self.validate_all(
"""
CREATE TABLE "Track"
Expand Down

0 comments on commit 838e780

Please sign in to comment.