Skip to content

Commit

Permalink
Feat: improve transpilation of datetime functions to Teradata (#3295)
Browse files Browse the repository at this point in the history
* fix: teradata cast to double precision

Casting to `DOUBLE` alone leads to a database error:
`Database reported error:3707:Syntax error, expected something like a
'PRECISION' keyword between the 'double' keyword and ')'.`

* fix: handle current_timestamp in teradata

`CURRENT_TIMESTAMP()` with parentheses requires specifying a precision in teradata.

* fix: handle date addition/subtraction in teradata

Transform the expression to an interval addition/subtraction. If the
interval is negated, use the opposite operator.

* fix: handle week/quarter intervals in teradata

* fix: handle extract quarter for teradata

Teradata doesn't support `EXTRACT(QUARTER FROM value)`, so use a
combination of `TO_CHAR` to get the quarter, and casting to int to
achieve the same result.

Ref: https://docs.teradata.com/r/Enterprise_IntelliFlex_VMware/SQL-Date-and-Time-Functions-and-Expressions/DateTime-and-Interval-Functions-and-Expressions/EXTRACT/EXTRACT-Syntax
  • Loading branch information
maureen-daum authored Apr 10, 2024
1 parent 2ea438b commit b28cd89
Show file tree
Hide file tree
Showing 4 changed files with 134 additions and 2 deletions.
50 changes: 50 additions & 0 deletions sqlglot/dialects/teradata.py
Original file line number Diff line number Diff line change
Expand Up @@ -13,6 +13,30 @@
from sqlglot.tokens import TokenType


def _date_add_sql(
kind: t.Literal["+", "-"],
) -> t.Callable[[Teradata.Generator, exp.DateAdd | exp.DateSub], str]:
def func(self: Teradata.Generator, expression: exp.DateAdd | exp.DateSub) -> str:
this = self.sql(expression, "this")
unit = expression.args.get("unit")

if expression.expression.is_negative:
kind_to_op = {"+": "-", "-": "+"}
simplify_expr = expression.expression.this
else:
kind_to_op = {"+": "+", "-": "-"}
simplify_expr = expression.expression

expression = self._simplify_unless_literal(simplify_expr)
if not isinstance(expression, exp.Literal):
self.unsupported("Cannot add non literal")

expression.set("is_string", True)
return f"{this} {kind_to_op[kind]} {self.sql(exp.Interval(this=expression, unit=unit))}"

return func


class Teradata(Dialect):
SUPPORTS_SEMI_ANTI_JOIN = False
TYPED_DIVISION = True
Expand Down Expand Up @@ -189,6 +213,7 @@ class Generator(generator.Generator):
TYPE_MAPPING = {
**generator.Generator.TYPE_MAPPING,
exp.DataType.Type.GEOMETRY: "ST_GEOMETRY",
exp.DataType.Type.DOUBLE: "DOUBLE PRECISION",
}

PROPERTIES_LOCATION = {
Expand All @@ -214,6 +239,9 @@ class Generator(generator.Generator):
exp.ToChar: lambda self, e: self.function_fallback_sql(e),
exp.ToNumber: to_number_with_nls_param,
exp.Use: lambda self, e: f"DATABASE {self.sql(e, 'this')}",
exp.CurrentTimestamp: lambda *_: "CURRENT_TIMESTAMP",
exp.DateAdd: _date_add_sql("+"),
exp.DateSub: _date_add_sql("-"),
}

def cast_sql(self, expression: exp.Cast, safe_prefix: t.Optional[str] = None) -> str:
Expand Down Expand Up @@ -276,3 +304,25 @@ def createable_sql(self, expression: exp.Create, locations: t.DefaultDict) -> st
return f"{this_name}{this_properties}{self.sep()}{this_schema}"

return super().createable_sql(expression, locations)

def extract_sql(self, expression: exp.Extract) -> str:
this = self.sql(expression, "this")
if this.upper() != "QUARTER":
return super().extract_sql(expression)

to_char = exp.func("to_char", expression.expression, exp.Literal.string("Q"))
return self.sql(exp.cast(to_char, "int"))

def interval_sql(self, expression: exp.Interval) -> str:
multiplier = 0
unit = expression.text("unit")

if unit.startswith("WEEK"):
multiplier = 7
elif unit.startswith("QUARTER"):
multiplier = 90

if multiplier:
return f"({multiplier} * {super().interval_sql(exp.Interval(this=expression.this, unit=exp.var('DAY')))})"

return super().interval_sql(expression)
2 changes: 1 addition & 1 deletion tests/dialects/test_dialect.py
Original file line number Diff line number Diff line change
Expand Up @@ -1667,7 +1667,7 @@ def test_operators(self):
"presto": "CAST(a AS DOUBLE) / b",
"redshift": "CAST(a AS DOUBLE PRECISION) / b",
"sqlite": "CAST(a AS REAL) / b",
"teradata": "CAST(a AS DOUBLE) / b",
"teradata": "CAST(a AS DOUBLE PRECISION) / b",
"trino": "CAST(a AS DOUBLE) / b",
"tsql": "CAST(a AS FLOAT) / b",
},
Expand Down
2 changes: 1 addition & 1 deletion tests/dialects/test_mysql.py
Original file line number Diff line number Diff line change
Expand Up @@ -1103,7 +1103,7 @@ def test_safe_div(self):
"presto": "CAST(a AS DOUBLE) / NULLIF(b, 0)",
"redshift": "CAST(a AS DOUBLE PRECISION) / NULLIF(b, 0)",
"sqlite": "CAST(a AS REAL) / b",
"teradata": "CAST(a AS DOUBLE) / NULLIF(b, 0)",
"teradata": "CAST(a AS DOUBLE PRECISION) / NULLIF(b, 0)",
"trino": "CAST(a AS DOUBLE) / NULLIF(b, 0)",
"tsql": "CAST(a AS FLOAT) / NULLIF(b, 0)",
},
Expand Down
82 changes: 82 additions & 0 deletions tests/dialects/test_teradata.py
Original file line number Diff line number Diff line change
Expand Up @@ -210,3 +210,85 @@ def test_cast(self):
"teradata": "TRYCAST('-2.5' AS DECIMAL(5, 2))",
},
)

def test_time(self):
self.validate_all(
"CURRENT_TIMESTAMP",
read={
"teradata": "CURRENT_TIMESTAMP",
"snowflake": "CURRENT_TIMESTAMP()",
},
)

self.validate_all(
"SELECT '2023-01-01' + INTERVAL '5' YEAR",
read={
"teradata": "SELECT '2023-01-01' + INTERVAL '5' YEAR",
"snowflake": "SELECT DATEADD(YEAR, 5, '2023-01-01')",
},
)
self.validate_all(
"SELECT '2023-01-01' - INTERVAL '5' YEAR",
read={
"teradata": "SELECT '2023-01-01' - INTERVAL '5' YEAR",
"snowflake": "SELECT DATEADD(YEAR, -5, '2023-01-01')",
},
)
self.validate_all(
"SELECT '2023-01-01' - INTERVAL '5' YEAR",
read={
"teradata": "SELECT '2023-01-01' - INTERVAL '5' YEAR",
"sqlite": "SELECT DATE_SUB('2023-01-01', 5, YEAR)",
},
)
self.validate_all(
"SELECT '2023-01-01' + INTERVAL '5' YEAR",
read={
"teradata": "SELECT '2023-01-01' + INTERVAL '5' YEAR",
"sqlite": "SELECT DATE_SUB('2023-01-01', -5, YEAR)",
},
)
self.validate_all(
"SELECT (90 * INTERVAL '1' DAY)",
read={
"teradata": "SELECT (90 * INTERVAL '1' DAY)",
"snowflake": "SELECT INTERVAL '1' QUARTER",
},
)
self.validate_all(
"SELECT (7 * INTERVAL '1' DAY)",
read={
"teradata": "SELECT (7 * INTERVAL '1' DAY)",
"snowflake": "SELECT INTERVAL '1' WEEK",
},
)
self.validate_all(
"SELECT '2023-01-01' + (90 * INTERVAL '5' DAY)",
read={
"teradata": "SELECT '2023-01-01' + (90 * INTERVAL '5' DAY)",
"snowflake": "SELECT DATEADD(QUARTER, 5, '2023-01-01')",
},
)
self.validate_all(
"SELECT '2023-01-01' + (7 * INTERVAL '5' DAY)",
read={
"teradata": "SELECT '2023-01-01' + (7 * INTERVAL '5' DAY)",
"snowflake": "SELECT DATEADD(WEEK, 5, '2023-01-01')",
},
)
self.validate_all(
"CAST(TO_CHAR(x, 'Q') AS INT)",
read={
"teradata": "CAST(TO_CHAR(x, 'Q') AS INT)",
"snowflake": "DATE_PART(QUARTER, x)",
"bigquery": "EXTRACT(QUARTER FROM x)",
},
)
self.validate_all(
"EXTRACT(MONTH FROM x)",
read={
"teradata": "EXTRACT(MONTH FROM x)",
"snowflake": "DATE_PART(MONTH, x)",
"bigquery": "EXTRACT(MONTH FROM x)",
},
)

0 comments on commit b28cd89

Please sign in to comment.