Add MSSQL support for Database#foreign_key_list #564

Merged
merged 1 commit into from Oct 17, 2012

Conversation

Projects
None yet
3 participants

munkyboy commented Oct 2, 2012

I'm not quite sure about the return value for the :table element. In the PostgreSQL adapter, if the table is schema bound, it returns a SQL::QualifiedIdentifier. I ended up going with the rule: try and match what Model.table_name would return.

I should note that I've only tested this on MSSQL 2008. It should work on 2005 as well.

Owner

jeremyevans commented Oct 2, 2012

This looks good. I think an SQL::QualifiedIdentifier makes the most sense in the schema qualified table case. Note that Model.table_name returns basically what you provide when creating the model. If you do class M < Sequel::Model(:schema__table), you'll probably get :schema__table. If you do class M < Sequel::Model(:table.qualify(:schema)), you'll probably get an SQL::QualifiedIdentifier instance.

I'm currently on vacation, and don't have access to my MSSQL test environment, so it will probably be a couple weeks until I can merge and test this. It will definitely get in before the next release.

Thanks for the help!

rohitn commented Oct 2, 2012

@munkyboy Is there a reason you chose to use SQL Server's sys. rather than INFORMATION_SCHEMA? The following works on SQL Server and PostgreSQL.

SELECT
  RC.CONSTRAINT_NAME CONSTRAINT_NAME
, RC.MATCH_OPTION MATCH_OPTION
, RC.UPDATE_RULE UPDATE_RULE
, RC.DELETE_RULE DELETE_RULE
, FK.TABLE_CATALOG TABLE_CATALOG
, FK.TABLE_SCHEMA TABLE_SCHEMA
, FK.TABLE_NAME TABLE_NAME
, FK_COLS.COLUMN_NAME COLUMN_NAME
, PK.TABLE_CATALOG REFERENCED_TABLE_CATALOG
, PK.TABLE_SCHEMA REFERENCED_TABLE_SCHEMA
, PK.TABLE_NAME REFERENCED_TABLE_NAME
, PK_COLS.COLUMN_NAME REFERENCED_COLUMN_NAME
FROM INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS RC
JOIN INFORMATION_SCHEMA.TABLE_CONSTRAINTS FK
 ON RC.CONSTRAINT_CATALOG = FK.CONSTRAINT_CATALOG
AND RC.CONSTRAINT_SCHEMA = FK.CONSTRAINT_SCHEMA
AND RC.CONSTRAINT_NAME = FK.CONSTRAINT_NAME
AND FK.CONSTRAINT_TYPE = 'FOREIGN KEY'
JOIN INFORMATION_SCHEMA.TABLE_CONSTRAINTS PK
 ON RC.UNIQUE_CONSTRAINT_CATALOG = PK.CONSTRAINT_CATALOG
AND RC.UNIQUE_CONSTRAINT_SCHEMA = PK.CONSTRAINT_SCHEMA
AND RC.UNIQUE_CONSTRAINT_NAME = PK.CONSTRAINT_NAME
AND PK.CONSTRAINT_TYPE = 'PRIMARY KEY'
JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE FK_COLS
 ON RC.CONSTRAINT_NAME = FK_COLS.CONSTRAINT_NAME
JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE PK_COLS
 ON PK.CONSTRAINT_NAME = PK_COLS.CONSTRAINT_NAME

munkyboy commented Oct 3, 2012

@rohitn no particular reason. In general, I feel like MSSQL catalog views are easier to deal with and provide more data compared to the information schema.

@jeremyevans jeremyevans merged commit 4f30f84 into jeremyevans:master Oct 17, 2012

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment