Skip to content

Commit

Permalink
feat: add support for foreign keys (#78)
Browse files Browse the repository at this point in the history
Google Cloud Spanner now supports Foreign Key Constraints. These now
also show up in the corresponding DatabaseMetaData methods.

Fixes #77
  • Loading branch information
olavloite committed Mar 9, 2020
1 parent 3d6f356 commit 9e770f2
Show file tree
Hide file tree
Showing 5 changed files with 383 additions and 62 deletions.
Expand Up @@ -14,21 +14,35 @@
* limitations under the License.
*/

SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM, PARENT.TABLE_NAME AS PKTABLE_NAME,
PARENT.COLUMN_NAME AS PKCOLUMN_NAME, CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
CHILD.TABLE_NAME AS FKTABLE_NAME, CHILD.COLUMN_NAME AS FKCOLUMN_NAME, CHILD.ORDINAL_POSITION AS KEY_SEQ, 3 AS UPDATE_RULE,
CASE WHEN TABLES.ON_DELETE_ACTION='CASCADE' THEN 0 ELSE 3 END AS DELETE_RULE, NULL AS FK_NAME, 'PRIMARY_KEY' AS PK_NAME,
7 AS DEFERRABILITY, TABLES.ON_DELETE_ACTION
FROM INFORMATION_SCHEMA.INDEX_COLUMNS PARENT
INNER JOIN INFORMATION_SCHEMA.INDEXES PARENT_INDEX ON PARENT.INDEX_NAME=PARENT_INDEX.INDEX_NAME AND PARENT.TABLE_NAME=PARENT_INDEX.TABLE_NAME AND PARENT.TABLE_SCHEMA=PARENT_INDEX.TABLE_SCHEMA AND PARENT.TABLE_CATALOG=PARENT_INDEX.TABLE_CATALOG AND PARENT_INDEX.INDEX_TYPE='PRIMARY_KEY'
INNER JOIN INFORMATION_SCHEMA.INDEX_COLUMNS CHILD ON NOT PARENT.TABLE_NAME=CHILD.TABLE_NAME AND PARENT.COLUMN_NAME=CHILD.COLUMN_NAME
INNER JOIN INFORMATION_SCHEMA.INDEXES CHILD_INDEX ON CHILD.INDEX_NAME=CHILD_INDEX.INDEX_NAME AND CHILD.TABLE_NAME=CHILD_INDEX.TABLE_NAME AND CHILD.TABLE_SCHEMA=CHILD_INDEX.TABLE_SCHEMA AND CHILD.TABLE_CATALOG=CHILD_INDEX.TABLE_CATALOG AND CHILD_INDEX.INDEX_TYPE='PRIMARY_KEY'
INNER JOIN INFORMATION_SCHEMA.TABLES ON CHILD.TABLE_CATALOG=TABLES.TABLE_CATALOG AND CHILD.TABLE_SCHEMA=TABLES.TABLE_SCHEMA AND CHILD.TABLE_NAME=TABLES.TABLE_NAME AND PARENT.TABLE_NAME=TABLES.PARENT_TABLE_NAME
WHERE PARENT_INDEX.INDEX_TYPE='PRIMARY_KEY' AND CHILD.ORDINAL_POSITION IS NOT NULL
AND UPPER(PARENT.TABLE_CATALOG) LIKE ?
AND UPPER(PARENT.TABLE_SCHEMA) LIKE ?
AND UPPER(PARENT.TABLE_NAME) LIKE ?
AND UPPER(CHILD.TABLE_CATALOG) LIKE ?
AND UPPER(CHILD.TABLE_SCHEMA) LIKE ?
AND UPPER(CHILD.TABLE_NAME) LIKE ?
ORDER BY CHILD.TABLE_CATALOG, CHILD.TABLE_SCHEMA, CHILD.TABLE_NAME, CHILD.ORDINAL_POSITION
SELECT *
FROM (
SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM, PARENT.TABLE_NAME AS PKTABLE_NAME,
PARENT.COLUMN_NAME AS PKCOLUMN_NAME, CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
CHILD.TABLE_NAME AS FKTABLE_NAME, CHILD.COLUMN_NAME AS FKCOLUMN_NAME, CHILD.ORDINAL_POSITION AS KEY_SEQ, 3 AS UPDATE_RULE,
CASE WHEN TABLES.ON_DELETE_ACTION='CASCADE' THEN 0 ELSE 3 END AS DELETE_RULE, NULL AS FK_NAME, 'PRIMARY_KEY' AS PK_NAME,
7 AS DEFERRABILITY
FROM INFORMATION_SCHEMA.INDEX_COLUMNS PARENT
INNER JOIN INFORMATION_SCHEMA.INDEXES PARENT_INDEX ON PARENT.INDEX_NAME=PARENT_INDEX.INDEX_NAME AND PARENT.TABLE_NAME=PARENT_INDEX.TABLE_NAME AND PARENT.TABLE_SCHEMA=PARENT_INDEX.TABLE_SCHEMA AND PARENT.TABLE_CATALOG=PARENT_INDEX.TABLE_CATALOG AND PARENT_INDEX.INDEX_TYPE='PRIMARY_KEY'
INNER JOIN INFORMATION_SCHEMA.INDEX_COLUMNS CHILD ON NOT PARENT.TABLE_NAME=CHILD.TABLE_NAME AND PARENT.COLUMN_NAME=CHILD.COLUMN_NAME
INNER JOIN INFORMATION_SCHEMA.INDEXES CHILD_INDEX ON CHILD.INDEX_NAME=CHILD_INDEX.INDEX_NAME AND CHILD.TABLE_NAME=CHILD_INDEX.TABLE_NAME AND CHILD.TABLE_SCHEMA=CHILD_INDEX.TABLE_SCHEMA AND CHILD.TABLE_CATALOG=CHILD_INDEX.TABLE_CATALOG AND CHILD_INDEX.INDEX_TYPE='PRIMARY_KEY'
INNER JOIN INFORMATION_SCHEMA.TABLES ON CHILD.TABLE_CATALOG=TABLES.TABLE_CATALOG AND CHILD.TABLE_SCHEMA=TABLES.TABLE_SCHEMA AND CHILD.TABLE_NAME=TABLES.TABLE_NAME AND PARENT.TABLE_NAME=TABLES.PARENT_TABLE_NAME
WHERE PARENT_INDEX.INDEX_TYPE='PRIMARY_KEY' AND CHILD.ORDINAL_POSITION IS NOT NULL

UNION ALL

SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM, PARENT.TABLE_NAME AS PKTABLE_NAME,
PARENT.COLUMN_NAME AS PKCOLUMN_NAME, CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
CHILD.TABLE_NAME AS FKTABLE_NAME, CHILD.COLUMN_NAME AS FKCOLUMN_NAME, CHILD.ORDINAL_POSITION AS KEY_SEQ, 3 AS UPDATE_RULE,
3 AS DELETE_RULE, CONSTRAINTS.CONSTRAINT_NAME AS FK_NAME, CONSTRAINTS.UNIQUE_CONSTRAINT_NAME AS PK_NAME,
7 AS DEFERRABILITY
FROM INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS CONSTRAINTS
INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE CHILD ON CONSTRAINTS.CONSTRAINT_CATALOG=CHILD.CONSTRAINT_CATALOG AND CONSTRAINTS.CONSTRAINT_SCHEMA= CHILD.CONSTRAINT_SCHEMA AND CONSTRAINTS.CONSTRAINT_NAME= CHILD.CONSTRAINT_NAME
INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE PARENT ON CONSTRAINTS.UNIQUE_CONSTRAINT_CATALOG=PARENT.CONSTRAINT_CATALOG AND CONSTRAINTS.UNIQUE_CONSTRAINT_SCHEMA=PARENT.CONSTRAINT_SCHEMA AND CONSTRAINTS.UNIQUE_CONSTRAINT_NAME=PARENT.CONSTRAINT_NAME AND PARENT.ORDINAL_POSITION=CHILD.POSITION_IN_UNIQUE_CONSTRAINT
) AS CROSS_REF
WHERE UPPER(PKTABLE_CAT) LIKE ?
AND UPPER(PKTABLE_SCHEM) LIKE ?
AND UPPER(PKTABLE_NAME) LIKE ?
AND UPPER(FKTABLE_CAT) LIKE ?
AND UPPER(FKTABLE_SCHEM) LIKE ?
AND UPPER(FKTABLE_NAME) LIKE ?
ORDER BY FKTABLE_CAT, FKTABLE_SCHEM, FKTABLE_NAME, KEY_SEQ
Expand Up @@ -14,21 +14,38 @@
* limitations under the License.
*/

SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM,
PARENT.TABLE_NAME AS PKTABLE_NAME, PARENT_INDEX_COLUMNS.COLUMN_NAME AS PKCOLUMN_NAME,
CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
CHILD.TABLE_NAME AS FKTABLE_NAME, PARENT_INDEX_COLUMNS.COLUMN_NAME AS FKCOLUMN_NAME,
PARENT_INDEX_COLUMNS.ORDINAL_POSITION AS KEY_SEQ,
1 AS UPDATE_RULE, -- 1 = importedKeyRestrict
CASE WHEN CHILD.ON_DELETE_ACTION='CASCADE' THEN 0 ELSE 1 END AS DELETE_RULE, -- 0 = cascade
NULL AS FK_NAME, 'PRIMARY_KEY' AS PK_NAME,
7 AS DEFERRABILITY -- 7 = importedKeyNotDeferrable
FROM INFORMATION_SCHEMA.TABLES PARENT
INNER JOIN INFORMATION_SCHEMA.TABLES CHILD ON CHILD.PARENT_TABLE_NAME=PARENT.TABLE_NAME
INNER JOIN INFORMATION_SCHEMA.INDEX_COLUMNS PARENT_INDEX_COLUMNS ON
PARENT_INDEX_COLUMNS.TABLE_NAME=PARENT.TABLE_NAME
AND PARENT_INDEX_COLUMNS.INDEX_NAME='PRIMARY_KEY'
WHERE UPPER(PARENT.TABLE_CATALOG) LIKE ?
AND UPPER(PARENT.TABLE_SCHEMA) LIKE ?
AND UPPER(PARENT.TABLE_NAME) LIKE ?
ORDER BY CHILD.TABLE_CATALOG, CHILD.TABLE_SCHEMA, CHILD.TABLE_NAME, PARENT_INDEX_COLUMNS.ORDINAL_POSITION
SELECT *
FROM (
SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM,
PARENT.TABLE_NAME AS PKTABLE_NAME, PARENT_INDEX_COLUMNS.COLUMN_NAME AS PKCOLUMN_NAME,
CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
CHILD.TABLE_NAME AS FKTABLE_NAME, PARENT_INDEX_COLUMNS.COLUMN_NAME AS FKCOLUMN_NAME,
PARENT_INDEX_COLUMNS.ORDINAL_POSITION AS KEY_SEQ,
1 AS UPDATE_RULE, -- 1 = importedKeyRestrict
CASE WHEN CHILD.ON_DELETE_ACTION='CASCADE' THEN 0 ELSE 1 END AS DELETE_RULE, -- 0 = cascade
NULL AS FK_NAME, 'PRIMARY_KEY' AS PK_NAME,
7 AS DEFERRABILITY -- 7 = importedKeyNotDeferrable
FROM INFORMATION_SCHEMA.TABLES PARENT
INNER JOIN INFORMATION_SCHEMA.TABLES CHILD ON CHILD.PARENT_TABLE_NAME=PARENT.TABLE_NAME
INNER JOIN INFORMATION_SCHEMA.INDEX_COLUMNS PARENT_INDEX_COLUMNS ON
PARENT_INDEX_COLUMNS.TABLE_NAME=PARENT.TABLE_NAME
AND PARENT_INDEX_COLUMNS.INDEX_NAME='PRIMARY_KEY'

UNION ALL

SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM, PARENT.TABLE_NAME AS PKTABLE_NAME,
PARENT.COLUMN_NAME AS PKCOLUMN_NAME, CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
CHILD.TABLE_NAME AS FKTABLE_NAME, CHILD.COLUMN_NAME AS FKCOLUMN_NAME,
CHILD.ORDINAL_POSITION AS KEY_SEQ,
1 AS UPDATE_RULE, -- 1 = importedKeyRestrict
1 AS DELETE_RULE, -- 1 = importedKeyRestrict
CONSTRAINTS.CONSTRAINT_NAME AS FK_NAME, CONSTRAINTS.UNIQUE_CONSTRAINT_NAME AS PK_NAME,
7 AS DEFERRABILITY -- 7 = importedKeyNotDeferrable
FROM INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS CONSTRAINTS
INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE CHILD ON CONSTRAINTS.CONSTRAINT_CATALOG=CHILD.CONSTRAINT_CATALOG AND CONSTRAINTS.CONSTRAINT_SCHEMA= CHILD.CONSTRAINT_SCHEMA AND CONSTRAINTS.CONSTRAINT_NAME= CHILD.CONSTRAINT_NAME
INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE PARENT ON CONSTRAINTS.UNIQUE_CONSTRAINT_CATALOG=PARENT.CONSTRAINT_CATALOG AND CONSTRAINTS.UNIQUE_CONSTRAINT_SCHEMA=PARENT.CONSTRAINT_SCHEMA AND CONSTRAINTS.UNIQUE_CONSTRAINT_NAME=PARENT.CONSTRAINT_NAME AND PARENT.ORDINAL_POSITION=CHILD.POSITION_IN_UNIQUE_CONSTRAINT
) EXPORTED_KEYS
WHERE UPPER(PKTABLE_CAT) LIKE ?
AND UPPER(PKTABLE_SCHEM) LIKE ?
AND UPPER(PKTABLE_NAME) LIKE ?
ORDER BY FKTABLE_CAT, FKTABLE_SCHEM, FKTABLE_NAME, KEY_SEQ
Expand Up @@ -14,21 +14,38 @@
* limitations under the License.
*/

SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM,
PARENT.TABLE_NAME AS PKTABLE_NAME, COL.COLUMN_NAME AS PKCOLUMN_NAME,
CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
CHILD.TABLE_NAME AS FKTABLE_NAME, COL.COLUMN_NAME FKCOLUMN_NAME,
COL.ORDINAL_POSITION AS KEY_SEQ,
1 AS UPDATE_RULE, -- 1 = importedKeyRestrict
CASE WHEN CHILD.ON_DELETE_ACTION = 'CASCADE' THEN 0 ELSE 1 END AS DELETE_RULE, -- 0 = cascade
NULL AS FK_NAME, INDEXES.INDEX_NAME AS PK_NAME,
7 AS DEFERRABILITY -- 7 = importedKeyNotDeferrable
FROM INFORMATION_SCHEMA.TABLES CHILD
INNER JOIN INFORMATION_SCHEMA.TABLES PARENT ON CHILD.TABLE_CATALOG=PARENT.TABLE_CATALOG AND CHILD.TABLE_SCHEMA=PARENT.TABLE_SCHEMA AND CHILD.PARENT_TABLE_NAME=PARENT.TABLE_NAME
INNER JOIN INFORMATION_SCHEMA.INDEXES ON PARENT.TABLE_CATALOG=INDEXES.TABLE_CATALOG AND PARENT.TABLE_SCHEMA=INDEXES.TABLE_SCHEMA AND PARENT.TABLE_NAME=INDEXES.TABLE_NAME AND INDEXES.INDEX_TYPE='PRIMARY_KEY'
INNER JOIN INFORMATION_SCHEMA.INDEX_COLUMNS COL ON INDEXES.TABLE_CATALOG=COL.TABLE_CATALOG AND INDEXES.TABLE_SCHEMA=COL.TABLE_SCHEMA AND INDEXES.TABLE_NAME=COL.TABLE_NAME AND INDEXES.INDEX_NAME=COL.INDEX_NAME
WHERE CHILD.PARENT_TABLE_NAME IS NOT NULL
AND UPPER(CHILD.TABLE_CATALOG) LIKE ?
AND UPPER(CHILD.TABLE_SCHEMA) LIKE ?
AND UPPER(CHILD.TABLE_NAME) LIKE ?
ORDER BY PARENT.TABLE_CATALOG, PARENT.TABLE_SCHEMA, PARENT.TABLE_NAME, COL.ORDINAL_POSITION
SELECT *
FROM (
SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM,
PARENT.TABLE_NAME AS PKTABLE_NAME, PARENT_INDEX_COLUMNS.COLUMN_NAME AS PKCOLUMN_NAME,
CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
CHILD.TABLE_NAME AS FKTABLE_NAME, PARENT_INDEX_COLUMNS.COLUMN_NAME AS FKCOLUMN_NAME,
PARENT_INDEX_COLUMNS.ORDINAL_POSITION AS KEY_SEQ,
1 AS UPDATE_RULE, -- 1 = importedKeyRestrict
CASE WHEN CHILD.ON_DELETE_ACTION='CASCADE' THEN 0 ELSE 1 END AS DELETE_RULE, -- 0 = cascade
NULL AS FK_NAME, 'PRIMARY_KEY' AS PK_NAME,
7 AS DEFERRABILITY -- 7 = importedKeyNotDeferrable
FROM INFORMATION_SCHEMA.TABLES PARENT
INNER JOIN INFORMATION_SCHEMA.TABLES CHILD ON CHILD.PARENT_TABLE_NAME=PARENT.TABLE_NAME
INNER JOIN INFORMATION_SCHEMA.INDEX_COLUMNS PARENT_INDEX_COLUMNS ON
PARENT_INDEX_COLUMNS.TABLE_NAME=PARENT.TABLE_NAME
AND PARENT_INDEX_COLUMNS.INDEX_NAME='PRIMARY_KEY'

UNION ALL

SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM, PARENT.TABLE_NAME AS PKTABLE_NAME,
PARENT.COLUMN_NAME AS PKCOLUMN_NAME, CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
CHILD.TABLE_NAME AS FKTABLE_NAME, CHILD.COLUMN_NAME AS FKCOLUMN_NAME,
CHILD.ORDINAL_POSITION AS KEY_SEQ,
1 AS UPDATE_RULE, -- 1 = importedKeyRestrict
1 AS DELETE_RULE, -- 1 = importedKeyRestrict
CONSTRAINTS.CONSTRAINT_NAME AS FK_NAME, CONSTRAINTS.UNIQUE_CONSTRAINT_NAME AS PK_NAME,
7 AS DEFERRABILITY -- 7 = importedKeyNotDeferrable
FROM INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS CONSTRAINTS
INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE CHILD ON CONSTRAINTS.CONSTRAINT_CATALOG=CHILD.CONSTRAINT_CATALOG AND CONSTRAINTS.CONSTRAINT_SCHEMA= CHILD.CONSTRAINT_SCHEMA AND CONSTRAINTS.CONSTRAINT_NAME= CHILD.CONSTRAINT_NAME
INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE PARENT ON CONSTRAINTS.UNIQUE_CONSTRAINT_CATALOG=PARENT.CONSTRAINT_CATALOG AND CONSTRAINTS.UNIQUE_CONSTRAINT_SCHEMA=PARENT.CONSTRAINT_SCHEMA AND CONSTRAINTS.UNIQUE_CONSTRAINT_NAME=PARENT.CONSTRAINT_NAME AND PARENT.ORDINAL_POSITION=CHILD.POSITION_IN_UNIQUE_CONSTRAINT
) IMPORTED_KEYS
WHERE UPPER(FKTABLE_CAT) LIKE ?
AND UPPER(FKTABLE_SCHEM) LIKE ?
AND UPPER(FKTABLE_NAME) LIKE ?
ORDER BY PKTABLE_CAT, PKTABLE_SCHEM, PKTABLE_NAME, KEY_SEQ

0 comments on commit 9e770f2

Please sign in to comment.