r"\s*SET\s+(?:(?:GLOBAL|SESSION)\s+)?\w", re.I | re.UNICODE
)
-
# old names
MSTime = TIME
MSSet = SET
cols = statement.table.c
clauses = []
+
+ requires_mysql8_alias = (
+ self.dialect._requires_alias_for_on_duplicate_key
+ )
+
+ if requires_mysql8_alias:
+ if statement.table.name.lower() == "new":
+ _on_dup_alias_name = "new_1"
+ else:
+ _on_dup_alias_name = "new"
+
# traverses through all table columns to preserve table column order
for column in (col for col in cols if col.key in on_duplicate.update):
-
val = on_duplicate.update[column.key]
if coercions._is_literal(val):
isinstance(obj, elements.ColumnClause)
and obj.table is on_duplicate.inserted_alias
):
- obj = literal_column(
- "VALUES(" + self.preparer.quote(obj.name) + ")"
- )
- return obj
+ if requires_mysql8_alias:
+ column_literal_clause = (
+ f"{_on_dup_alias_name}."
+ f"{self.preparer.quote(obj.name)}"
+ )
+ else:
+ column_literal_clause = (
+ f"VALUES({self.preparer.quote(obj.name)})"
+ )
+ return literal_column(column_literal_clause)
else:
# element is not replaced
return None
)
)
- return "ON DUPLICATE KEY UPDATE " + ", ".join(clauses)
+ if requires_mysql8_alias:
+ return (
+ f"AS {_on_dup_alias_name} "
+ f"ON DUPLICATE KEY UPDATE {', '.join(clauses)}"
+ )
+ else:
+ return f"ON DUPLICATE KEY UPDATE {', '.join(clauses)}"
def visit_concat_op_expression_clauselist(
self, clauselist, operator, **kw
supports_for_update_of = False # default for MySQL ...
# ... may be updated to True for MySQL 8+ in initialize()
+ _requires_alias_for_on_duplicate_key = False # Only available ...
+ # ... in MySQL 8+
+
# MySQL doesn't support "DEFAULT VALUES" but *does* support
# "VALUES (DEFAULT)"
supports_default_values = False
self.is_mariadb and self.server_version_info >= (10, 5)
)
+ self._requires_alias_for_on_duplicate_key = (
+ self._is_mysql and self.server_version_info >= (8, 0, 20)
+ )
+
self._warn_for_known_db_issues()
def _warn_for_known_db_issues(self):
from sqlalchemy.testing import expect_warnings
from sqlalchemy.testing import fixtures
from sqlalchemy.testing import mock
+from sqlalchemy.testing import Variation
class ReservedWordFixture(AssertsCompiledSQL):
bar=stmt.inserted.bar, baz=stmt.inserted.baz
)
- def test_from_values(self):
+ @testing.variation("version", ["mysql8", "all_others"])
+ def test_from_values(self, version: Variation):
stmt = insert(self.table).values(
[{"id": 1, "bar": "ab"}, {"id": 2, "bar": "b"}]
)
stmt = stmt.on_duplicate_key_update(
bar=stmt.inserted.bar, baz=stmt.inserted.baz
)
- expected_sql = (
- "INSERT INTO foos (id, bar) VALUES (%s, %s), (%s, %s) "
- "ON DUPLICATE KEY UPDATE bar = VALUES(bar), baz = VALUES(baz)"
- )
- self.assert_compile(stmt, expected_sql)
+
+ if version.all_others:
+ expected_sql = (
+ "INSERT INTO foos (id, bar) VALUES (%s, %s), (%s, %s) "
+ "ON DUPLICATE KEY UPDATE bar = VALUES(bar), baz = VALUES(baz)"
+ )
+ dialect = None
+ elif version.mysql8:
+ expected_sql = (
+ "INSERT INTO foos (id, bar) VALUES (%s, %s), (%s, %s) "
+ "AS new ON DUPLICATE KEY UPDATE "
+ "bar = new.bar, "
+ "baz = new.baz"
+ )
+ dialect = mysql.dialect()
+ dialect._requires_alias_for_on_duplicate_key = True
+ else:
+ version.fail()
+
+ self.assert_compile(stmt, expected_sql, dialect=dialect)
def test_from_literal(self):
stmt = insert(self.table).values(
)
self.assert_compile(stmt, expected_sql)
- def test_update_sql_expr(self):
+ @testing.variation("version", ["mysql8", "all_others"])
+ def test_update_sql_expr(self, version: Variation):
stmt = insert(self.table).values(
[{"id": 1, "bar": "ab"}, {"id": 2, "bar": "b"}]
)
bar=func.coalesce(stmt.inserted.bar),
baz=stmt.inserted.baz + "some literal" + stmt.inserted.bar,
)
+
+ if version.all_others:
+ expected_sql = (
+ "INSERT INTO foos (id, bar) VALUES (%s, %s), (%s, %s) ON "
+ "DUPLICATE KEY UPDATE bar = coalesce(VALUES(bar)), "
+ "baz = (concat(VALUES(baz), %s, VALUES(bar)))"
+ )
+ dialect = None
+ elif version.mysql8:
+
+ expected_sql = (
+ "INSERT INTO foos (id, bar) VALUES (%s, %s), (%s, %s) "
+ "AS new ON DUPLICATE KEY UPDATE bar = "
+ "coalesce(new.bar), "
+ "baz = (concat(new.baz, %s, "
+ "new.bar))"
+ )
+ dialect = mysql.dialect()
+ dialect._requires_alias_for_on_duplicate_key = True
+ else:
+ version.fail()
+
+ self.assert_compile(
+ stmt,
+ expected_sql,
+ checkparams={
+ "id_m0": 1,
+ "bar_m0": "ab",
+ "id_m1": 2,
+ "bar_m1": "b",
+ "baz_1": "some literal",
+ },
+ dialect=dialect,
+ )
+
+ def test_mysql8_on_update_dont_dup_alias_name(self):
+ t = table("new", column("id"), column("bar"), column("baz"))
+ stmt = insert(t).values(
+ [{"id": 1, "bar": "ab"}, {"id": 2, "bar": "b"}]
+ )
+ stmt = stmt.on_duplicate_key_update(
+ bar=func.coalesce(stmt.inserted.bar),
+ baz=stmt.inserted.baz + "some literal" + stmt.inserted.bar,
+ )
+
expected_sql = (
- "INSERT INTO foos (id, bar) VALUES (%s, %s), (%s, %s) ON "
- "DUPLICATE KEY UPDATE bar = coalesce(VALUES(bar)), "
- "baz = (concat(VALUES(baz), %s, VALUES(bar)))"
+ "INSERT INTO new (id, bar) VALUES (%s, %s), (%s, %s) "
+ "AS new_1 ON DUPLICATE KEY UPDATE bar = "
+ "coalesce(new_1.bar), "
+ "baz = (concat(new_1.baz, %s, "
+ "new_1.bar))"
)
+ dialect = mysql.dialect()
+ dialect._requires_alias_for_on_duplicate_key = True
self.assert_compile(
stmt,
expected_sql,
"bar_m1": "b",
"baz_1": "some literal",
},
+ dialect=dialect,
)