Skip to content

Commit f0243f0

Browse files
committed
fix: Return Correct Column Order in get_multi_foreign_keys
Ensure both referred and constrained columns reported by `get_multi_foreign_keys` are in the same order matching the constraint declaration. Uses information for the unique constraint corresponding to the foreign key constraint in order to ensure its columns are ordered correctly. Previously, the `CONSTRAINT_COLUMN` view in the information schema was used to retrieve the referred columns, and that view offers no information about column order. Instead, we use the KEY_COLUMN_USAGE view for the corresponding unique constraint, which is ordered. This requires consulting the `REFERENTIAL_CONSTRAINTS` view in order to find the unique constraint associated with the foreign key. Unfortunately, this view has a [bug in the emulator](GoogleCloudPlatform/cloud-spanner-emulator#279) related to cross-schema foreign keys. I had to skip a test for cross-schema foreign keys due to the emulator issue. I've confirmed a real spanner does not have this issue. fixes: #779
1 parent daf35a7 commit f0243f0

File tree

2 files changed

+84
-42
lines changed

2 files changed

+84
-42
lines changed

google/cloud/sqlalchemy_spanner/sqlalchemy_spanner.py

Lines changed: 33 additions & 41 deletions
Original file line numberDiff line numberDiff line change
@@ -1513,40 +1513,45 @@ def get_multi_foreign_keys(
15131513
tc.table_schema,
15141514
tc.table_name,
15151515
tc.constraint_name,
1516-
ctu.table_name,
1517-
ctu.table_schema,
1518-
ARRAY_AGG(DISTINCT ccu.column_name),
1519-
ARRAY_AGG(
1520-
DISTINCT CONCAT(
1521-
CAST(kcu.ordinal_position AS STRING),
1522-
'_____',
1523-
kcu.column_name
1524-
)
1516+
tc_uq.table_name,
1517+
tc_uq.table_schema,
1518+
-- Find the corresponding pairs of columns for the foreign key constraint
1519+
-- and its related unique constraint.
1520+
ARRAY(
1521+
SELECT (kcu.column_name, kcu_uq.column_name)
1522+
FROM information_schema.key_column_usage AS kcu
1523+
JOIN information_schema.key_column_usage AS kcu_uq
1524+
ON kcu_uq.constraint_catalog = rc.unique_constraint_catalog
1525+
AND kcu_uq.constraint_schema = rc.unique_constraint_schema
1526+
AND kcu_uq.constraint_name = rc.unique_constraint_name
1527+
AND kcu_uq.ordinal_position = kcu.ordinal_position
1528+
WHERE
1529+
kcu.constraint_catalog = tc.constraint_catalog
1530+
AND kcu.constraint_schema = tc.constraint_schema
1531+
AND kcu.constraint_name = tc.constraint_name
1532+
ORDER BY kcu.ordinal_position
15251533
)
15261534
FROM information_schema.table_constraints AS tc
1527-
JOIN information_schema.constraint_column_usage AS ccu
1528-
ON ccu.constraint_catalog = tc.table_catalog
1529-
and ccu.constraint_schema = tc.table_schema
1530-
and ccu.constraint_name = tc.constraint_name
1531-
JOIN information_schema.constraint_table_usage AS ctu
1532-
ON ctu.constraint_catalog = tc.table_catalog
1533-
and ctu.constraint_schema = tc.table_schema
1534-
and ctu.constraint_name = tc.constraint_name
1535-
JOIN information_schema.key_column_usage AS kcu
1536-
ON kcu.table_catalog = tc.table_catalog
1537-
and kcu.table_schema = tc.table_schema
1538-
and kcu.constraint_name = tc.constraint_name
1535+
-- Join the foreign key constraint for the referring table.
1536+
JOIN information_schema.referential_constraints AS rc
1537+
ON rc.constraint_catalog = tc.constraint_catalog
1538+
AND rc.constraint_schema = tc.constraint_schema
1539+
AND rc.constraint_name = tc.constraint_name
1540+
-- Join the corresponding unique constraint on the referenced table.
1541+
JOIN information_schema.table_constraints AS tc_uq
1542+
ON tc_uq.constraint_catalog = rc.unique_constraint_catalog
1543+
AND tc_uq.constraint_schema = rc.unique_constraint_schema
1544+
AND tc_uq.constraint_name = rc.unique_constraint_name
1545+
-- Join in the tables view so WHERE filters can reference fields in it.
15391546
JOIN information_schema.tables AS t
15401547
ON t.table_catalog = tc.table_catalog
1541-
and t.table_schema = tc.table_schema
1542-
and t.table_name = tc.table_name
1548+
AND t.table_schema = tc.table_schema
1549+
AND t.table_name = tc.table_name
15431550
WHERE
15441551
{table_filter_query}
15451552
{table_type_query}
15461553
{schema_filter_query}
15471554
tc.constraint_type = "FOREIGN KEY"
1548-
GROUP BY tc.table_name, tc.table_schema, tc.constraint_name,
1549-
ctu.table_name, ctu.table_schema
15501555
""".format(
15511556
table_filter_query=table_filter_query,
15521557
table_type_query=table_type_query,
@@ -1558,29 +1563,16 @@ def get_multi_foreign_keys(
15581563
result_dict = {}
15591564

15601565
for row in rows:
1561-
# Due to Spanner limitations, arrays order is not guaranteed during
1562-
# aggregation. Still, for constraints it's vital to keep the order
1563-
# of the referred columns, otherwise SQLAlchemy and Alembic may start
1564-
# to occasionally drop and recreate constraints. To avoid this, the
1565-
# method uses prefixes with the `key_column_usage.ordinal_position`
1566-
# values to ensure the columns are aggregated into an array in the
1567-
# correct order. Prefixes are only used under the hood. For more details
1568-
# see the issue:
1569-
# https://github.com/googleapis/python-spanner-sqlalchemy/issues/271
1570-
#
1571-
# The solution seem a bit clumsy, and should be improved as soon as a
1572-
# better approach found.
15731566
row[0] = row[0] or None
15741567
table_info = result_dict.get((row[0], row[1]), [])
1575-
for index, value in enumerate(sorted(row[6])):
1576-
row[6][index] = value.split("_____")[1]
15771568

1569+
constrained_columns, referred_columns = zip(*row[5])
15781570
fk_info = {
15791571
"name": row[2],
15801572
"referred_table": row[3],
15811573
"referred_schema": row[4] or None,
1582-
"referred_columns": row[5],
1583-
"constrained_columns": row[6],
1574+
"referred_columns": list(referred_columns),
1575+
"constrained_columns": list(constrained_columns),
15841576
}
15851577

15861578
table_info.append(fk_info)

test/system/test_basics.py

Lines changed: 51 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -14,12 +14,15 @@
1414
import datetime
1515
import os
1616
from typing import Optional
17+
18+
import pytest
1719
from sqlalchemy import (
1820
text,
1921
Table,
2022
Column,
2123
Integer,
2224
ForeignKey,
25+
ForeignKeyConstraint,
2326
PrimaryKeyConstraint,
2427
String,
2528
Index,
@@ -96,6 +99,25 @@ def define_tables(cls, metadata):
9699
Column("color", String(20)),
97100
schema="schema",
98101
)
102+
# Add a composite primary key & foreign key example.
103+
Table(
104+
"composite_pk",
105+
metadata,
106+
Column("a", String, primary_key=True),
107+
Column("b", String, primary_key=True),
108+
)
109+
Table(
110+
"composite_fk",
111+
metadata,
112+
Column("my_a", String, primary_key=True),
113+
Column("my_b", String, primary_key=True),
114+
Column("my_c", String, primary_key=True),
115+
ForeignKeyConstraint(
116+
["my_a", "my_b"],
117+
["composite_pk.a", "composite_pk.b"],
118+
name="composite_fk_composite_pk_a_b",
119+
),
120+
)
99121

100122
def test_hello_world(self, connection):
101123
greeting = connection.execute(text("select 'Hello World'"))
@@ -115,7 +137,7 @@ def test_reflect(self, connection):
115137
engine = connection.engine
116138
meta: MetaData = MetaData()
117139
meta.reflect(bind=engine)
118-
eq_(3, len(meta.tables))
140+
eq_(5, len(meta.tables))
119141
table = meta.tables["numbers"]
120142
eq_(5, len(table.columns))
121143
eq_("number", table.columns[0].name)
@@ -269,6 +291,13 @@ class User(Base):
269291
eq_(len(inserted_rows), len(selected_rows))
270292
eq_(set(inserted_rows), set(selected_rows))
271293

294+
@pytest.mark.skipif(
295+
os.environ.get("SPANNER_EMULATOR_HOST") is not None,
296+
reason=(
297+
"Fails in emulator due to bug: "
298+
"https://github.com/GoogleCloudPlatform/cloud-spanner-emulator/issues/279"
299+
),
300+
)
272301
def test_cross_schema_fk_lookups(self, connection):
273302
"""Ensures we introspect FKs within & across schema."""
274303

@@ -306,6 +335,27 @@ def test_cross_schema_fk_lookups(self, connection):
306335
),
307336
)
308337

338+
def test_composite_fk_lookups(self, connection):
339+
"""Ensures we introspect composite FKs."""
340+
341+
engine = connection.engine
342+
343+
insp = inspect(engine)
344+
eq_(
345+
{
346+
(None, "composite_fk"): [
347+
{
348+
"name": "composite_fk_composite_pk_a_b",
349+
"referred_table": "composite_pk",
350+
"referred_schema": None,
351+
"referred_columns": ["a", "b"],
352+
"constrained_columns": ["my_a", "my_b"],
353+
}
354+
]
355+
},
356+
insp.get_multi_foreign_keys(filter_names=["composite_fk"]),
357+
)
358+
309359
def test_commit_timestamp(self, connection):
310360
"""Ensures commit timestamps are set."""
311361

0 commit comments

Comments
 (0)