Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Fix(snowflake): convert VALUES with invalid expressions into UNION ALL #3213

Merged
merged 1 commit into from Mar 25, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
10 changes: 10 additions & 0 deletions sqlglot/dialects/snowflake.py
Expand Up @@ -852,6 +852,16 @@ class Generator(generator.Generator):
exp.VolatileProperty: exp.Properties.Location.UNSUPPORTED,
}

UNSUPPORTED_VALUES_EXPRESSIONS = {
exp.Struct,
}

def values_sql(self, expression: exp.Values, values_as_table: bool = True) -> str:
if expression.find(*self.UNSUPPORTED_VALUES_EXPRESSIONS):
values_as_table = False

return super().values_sql(expression, values_as_table=values_as_table)

def datatype_sql(self, expression: exp.DataType) -> str:
expressions = expression.expressions
if (
Expand Down
6 changes: 4 additions & 2 deletions sqlglot/generator.py
Expand Up @@ -1746,9 +1746,11 @@ def update_sql(self, expression: exp.Update) -> str:
sql = f"UPDATE {this} SET {set_sql}{expression_sql}{order}{limit}"
return self.prepend_ctes(expression, sql)

def values_sql(self, expression: exp.Values) -> str:
def values_sql(self, expression: exp.Values, values_as_table: bool = True) -> str:
values_as_table = values_as_table and self.VALUES_AS_TABLE

# The VALUES clause is still valid in an `INSERT INTO ..` statement, for example
if self.VALUES_AS_TABLE or not expression.find_ancestor(exp.From, exp.Join):
if values_as_table or not expression.find_ancestor(exp.From, exp.Join):
args = self.expressions(expression)
alias = self.sql(expression, "alias")
values = f"VALUES{self.seg('')}{args}"
Expand Down
13 changes: 12 additions & 1 deletion tests/dialects/test_snowflake.py
Expand Up @@ -1416,14 +1416,25 @@ def test_values(self):
"spark": "SELECT `c0`, `c1` FROM (VALUES (1, 2), (3, 4)) AS `t0`(`c0`, `c1`)",
},
)

self.validate_all(
"""SELECT $1 AS "_1" FROM VALUES ('a'), ('b')""",
write={
"snowflake": """SELECT $1 AS "_1" FROM (VALUES ('a'), ('b'))""",
"spark": """SELECT ${1} AS `_1` FROM VALUES ('a'), ('b')""",
},
)
self.validate_all(
"SELECT * FROM (SELECT OBJECT_CONSTRUCT('a', 1) AS x) AS t",
read={
"duckdb": "SELECT * FROM (VALUES ({'a': 1})) AS t(x)",
},
)
self.validate_all(
"SELECT * FROM (SELECT OBJECT_CONSTRUCT('a', 1) AS x UNION ALL SELECT OBJECT_CONSTRUCT('a', 2)) AS t",
read={
"duckdb": "SELECT * FROM (VALUES ({'a': 1}), ({'a': 2})) AS t(x)",
},
)

def test_describe_table(self):
self.validate_all(
Expand Down