--- /dev/null
+.. change::
+ :tags: bug, oracle, performance
+ :tickets: 4486
+
+ Added a CAST(VARCHAR2(128)) to the "table name", "owner", and other
+ DDL-name parameters as used in reflection queries against Oracle system
+ views such as ALL_TABLES, ALL_TAB_CONSTRAINTS, etc to better enable
+ indexing to take place against these columns, as they previously would be
+ implicitly handled as NVARCHAR2 due to Python's use of Unicode for strings;
+ these columns are documented in all Oracle versions as being VARCHAR2 with
+ lengths varying from 30 to 128 characters depending on server version.
+ Additionally, test support has been enabled for Unicode-named DDL
+ structures against Oracle databases.
if not schema:
schema = self.default_schema_name
+
cursor = connection.execute(
sql.text(
"SELECT table_name FROM all_tables "
- "WHERE table_name = :name AND owner = :schema_name"
+ "WHERE table_name = CAST(:name AS VARCHAR2(128)) "
+ "AND owner = CAST(:schema_name AS VARCHAR2(128))"
),
dict(
name=self.denormalize_name(table_name),
clauses = []
params = {}
if desired_synonym:
- clauses.append("synonym_name = :synonym_name")
+ clauses.append(
+ "synonym_name = CAST(:synonym_name AS VARCHAR2(128))"
+ )
params["synonym_name"] = desired_synonym
if desired_owner:
- clauses.append("owner = :desired_owner")
+ clauses.append("owner = CAST(:desired_owner AS VARCHAR2(128))")
params["desired_owner"] = desired_owner
if desired_table:
- clauses.append("table_name = :tname")
+ clauses.append("table_name = CAST(:tname AS VARCHAR2(128))")
params["tname"] = desired_table
q += " AND ".join(clauses)
text = (
"SELECT %(columns)s "
"FROM ALL_TABLES%(dblink)s "
- "WHERE table_name = :table_name"
+ "WHERE table_name = CAST(:table_name AS VARCHAR(128))"
)
if schema is not None:
params["owner"] = schema
- text += " AND owner = :owner "
+ text += " AND owner = CAST(:owner AS VARCHAR(128)) "
text = text % {"dblink": dblink, "columns": ", ".join(columns)}
result = connection.execute(sql.text(text), params)
identity_cols = "NULL as default_on_null, NULL as identity_options"
params = {"table_name": table_name}
+
text = """
SELECT
col.column_name,
ON col.table_name = com.table_name
AND col.column_name = com.column_name
AND col.owner = com.owner
- WHERE col.table_name = :table_name
+ WHERE col.table_name = CAST(:table_name AS VARCHAR2(128))
AND col.hidden_column = 'NO'
"""
if schema is not None:
COMMENT_SQL = """
SELECT comments
FROM all_tab_comments
- WHERE table_name = :table_name AND owner = :schema_name
+ WHERE table_name = CAST(:table_name AS VARCHAR(128))
+ AND owner = CAST(:schema_name AS VARCHAR(128))
"""
c = connection.execute(
"\na.index_name = b.index_name "
"\nAND a.table_owner = b.table_owner "
"\nAND a.table_name = b.table_name "
- "\nAND a.table_name = :table_name "
+ "\nAND a.table_name = CAST(:table_name AS VARCHAR(128))"
)
if schema is not None:
"\nFROM all_constraints%(dblink)s ac,"
"\nall_cons_columns%(dblink)s loc,"
"\nall_cons_columns%(dblink)s rem"
- "\nWHERE ac.table_name = :table_name"
+ "\nWHERE ac.table_name = CAST(:table_name AS VARCHAR2(128))"
"\nAND ac.constraint_type IN ('R','P', 'U', 'C')"
)
if schema is not None:
params["owner"] = schema
- text += "\nAND ac.owner = :owner"
+ text += "\nAND ac.owner = CAST(:owner AS VARCHAR2(128))"
text += (
"\nAND ac.owner = loc.owner"