Skip to content

Commit 7d91cd6

Browse files
authored
fix: Escaping in SQL templates for qmark parameter style (#27)
* fix: Escaping in SQL templates for `qmark` parameter style * fix: Align DuckDB with `qmark` fixes * chore: Clean up parameter style handling for DuckDB dialect * chore: Cover default DuckDB parameter style handling with test
1 parent cc6a555 commit 7d91cd6

File tree

4 files changed

+56
-14
lines changed

4 files changed

+56
-14
lines changed

deepnote_toolkit/sql/jinjasql_utils.py

Lines changed: 14 additions & 9 deletions
Original file line numberDiff line numberDiff line change
@@ -20,13 +20,13 @@ def render_jinja_sql_template(template, param_style=None):
2020
str: The rendered SQL query.
2121
"""
2222

23-
escaped_template = _escape_jinja_template(template)
24-
2523
# Default to pyformat for backwards compatibility
2624
# Note: Some databases like Trino require "qmark" or "format" style
27-
jinja_sql = JinjaSql(
28-
param_style=param_style if param_style is not None else "pyformat"
29-
)
25+
effective_param_style = param_style if param_style is not None else "pyformat"
26+
27+
escaped_template = _escape_jinja_template(template, effective_param_style)
28+
29+
jinja_sql = JinjaSql(param_style=effective_param_style)
3030
parsed_content = jinja_sql.env.parse(escaped_template)
3131
required_variables = meta.find_undeclared_variables(parsed_content)
3232
jinja_sql_data = {
@@ -40,9 +40,14 @@ def _get_variable_value(variable_name):
4040
return getattr(__main__, variable_name)
4141

4242

43-
def _escape_jinja_template(template):
43+
def _escape_jinja_template(template, param_style: str = "pyformat"):
4444
# see https://github.com/sripathikrishnan/jinjasql/issues/28 and https://stackoverflow.com/q/8657508/2761695
4545
# we have to replace % by %% in the SQL query due to how SQL alchemy interprets %
46-
# but only if the { is not preceded by { or followed by }, because those are jinja blocks
47-
# we use lookbehind ?<= and lookahead ?= regex matchers to capture the { and } symbols
48-
return re.sub(r"(?<=[^{])%(?=[^}])", "%%", template)
46+
# but ONLY for param styles that use % (format and pyformat)
47+
# For other param styles (qmark), % has no special meaning
48+
# and should not be escaped (e.g., in date format strings like '%m-%d-%Y')
49+
if param_style in ("format", "pyformat"):
50+
# Only escape % if it's not part of a jinja block (not preceded by { or followed by })
51+
# we use lookbehind ?<= and lookahead ?= regex matchers to capture the { and } symbols
52+
return re.sub(r"(?<=[^{])%(?=[^}])", "%%", template)
53+
return template

deepnote_toolkit/sql/sql_execution.py

Lines changed: 3 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -156,7 +156,8 @@ class ExecuteSqlError(Exception):
156156
url_obj = make_url(sql_alchemy_dict["url"])
157157
# Mapping of SQLAlchemy dialect names to their required param_style
158158
dialect_param_styles = {
159-
"trino": "qmark", # Trino requires ? placeholders with list/tuple params
159+
"trino": "qmark", # Trino only supports qmark style
160+
"deepnote+duckdb": "qmark", # DuckDB officially recommends qmark style (doesn't support pyformat)
160161
}
161162
param_style = dialect_param_styles.get(url_obj.drivername)
162163

@@ -294,10 +295,7 @@ def _execute_sql_with_caching(
294295
):
295296
# duckdb SQL is not cached, so we can skip the logic below for duckdb
296297
if requires_duckdb:
297-
# duckdb requires % to be unescaped, but other dialects require it to be escaped as %%
298-
# https://docs.sqlalchemy.org/en/14/faq/sqlexpressions.html#why-are-percent-signs-being-doubled-up-when-stringifying-sql-statements
299-
query_unescaped = query % () if query else query
300-
dataframe = execute_duckdb_sql(query_unescaped, bind_params)
298+
dataframe = execute_duckdb_sql(query, bind_params)
301299
# for Chained SQL we return the dataframe with the SQL source attached as DeepnoteQueryPreview object
302300
if return_variable_type == "query_preview":
303301
return _convert_dataframe_to_query_preview(dataframe, query_preview_source)

tests/unit/test_jinjasql_utils.py

Lines changed: 26 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -89,6 +89,32 @@ def test_qmark_format(self):
8989
self.assertEqual(query.strip(), "SELECT * FROM users WHERE id = ?")
9090
self.assertEqual(bind_params, ["test"])
9191

92+
def test_qmark_escaping(self):
93+
template = "SELECT date_format(TIMESTAMP '2022-10-20 05:10:00', '%m-%d-%Y %H')"
94+
95+
query, bind_params = render_jinja_sql_template(template, param_style="qmark")
96+
97+
self.assertEqual(query, template)
98+
self.assertEqual(bind_params, [])
99+
100+
def test_pyformat_escaping(self):
101+
query, bind_params = render_jinja_sql_template(
102+
"SELECT '% character'",
103+
param_style="pyformat",
104+
)
105+
106+
self.assertEqual(query, "SELECT '%% character'")
107+
self.assertEqual(bind_params, {})
108+
109+
def test_format_escaping(self):
110+
query, bind_params = render_jinja_sql_template(
111+
"SELECT '% character'",
112+
param_style="format",
113+
)
114+
115+
self.assertEqual(query, "SELECT '%% character'")
116+
self.assertEqual(bind_params, [])
117+
92118

93119
if __name__ == "__main__":
94120
unittest.main()

tests/unit/test_sql_execution.py

Lines changed: 13 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -60,6 +60,19 @@ def test_duckdb_concat_with_percentage_sign(self):
6060
self.assertEqual(result.iloc[0]["percentage_string"], "25.5%")
6161
self.assertNotEqual(result.iloc[0]["percentage_string"], "25.5%%")
6262

63+
def test_duckdb_defaults_to_qmark_param_style(self):
64+
os.environ["SQL_DEEPNOTE_DATAFRAME_SQL"] = (
65+
'{"url":"deepnote+duckdb:///:memory:","params":{},"param_style":null}'
66+
)
67+
68+
result = execute_sql(
69+
"SELECT '%' as value",
70+
"SQL_DEEPNOTE_DATAFRAME_SQL",
71+
)
72+
73+
assert result is not None
74+
self.assertEqual(result.iloc[0]["value"], "%")
75+
6376
@mock.patch("deepnote_toolkit.sql.sql_execution._execute_sql_on_engine")
6477
@mock.patch("sqlalchemy.engine.create_engine")
6578
def test_delete_sql_that_doesnt_produce_a_dataframe(

0 commit comments

Comments
 (0)