Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with
or
.
Download ZIP

Loading…

Add MSSQL support for Database#foreign_key_list #564

Merged
merged 1 commit into from

3 participants

@munkyboy

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.

@jeremyevans
Owner

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

@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

@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
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Commits on Oct 2, 2012
This page is out of date. Refresh to see the latest.
Showing with 120 additions and 0 deletions.
  1. +42 −0 lib/sequel/adapters/shared/mssql.rb
  2. +78 −0 spec/adapters/mssql_spec.rb
View
42 lib/sequel/adapters/shared/mssql.rb
@@ -13,6 +13,7 @@ module DatabaseMethods
SQL_ROLLBACK_TO_SAVEPOINT = 'IF @@TRANCOUNT > 0 ROLLBACK TRANSACTION autopoint_%d'.freeze
SQL_SAVEPOINT = 'SAVE TRANSACTION autopoint_%d'.freeze
MSSQL_DEFAULT_RE = /\A(?:\(N?('.*')\)|\(\((-?\d+(?:\.\d+)?)\)\))\z/
+ FOREIGN_KEY_ACTION_MAP = {0 => :no_action, 1 => :cascade, 2 => :set_null, 3 => :set_default}.freeze
include Sequel::Database::SplitAlterTable
@@ -36,6 +37,47 @@ def global_index_namespace?
false
end
+ # Return foreign key information using the system views, including
+ # :name, :on_delete, and :on_update entries in the hashes.
+ def foreign_key_list(table, opts={})
+ m = output_identifier_meth
+ im = input_identifier_meth
+ schema, table = schema_and_table(table)
+ current_schema = m.call(get(Sequel.function('schema_name')))
+ fk_action_map = FOREIGN_KEY_ACTION_MAP
+ ds = metadata_dataset.from(:sys__foreign_keys___fk).
+ join(:sys__foreign_key_columns___fkc, :constraint_object_id => :object_id).
+ join(:sys__all_columns___pc, :object_id => :fkc__parent_object_id, :column_id => :fkc__parent_column_id).
+ join(:sys__all_columns___rc, :object_id => :fkc__referenced_object_id, :column_id => :fkc__referenced_column_id).
+ where{{object_schema_name(:fk__parent_object_id) => im.call(schema || current_schema)}}.
+ where{{object_name(:fk__parent_object_id) => im.call(table)}}.
+ select{[:fk__name,
+ :fk__delete_referential_action,
+ :fk__update_referential_action,
+ :pc__name___column,
+ :rc__name___referenced_column,
+ object_schema_name(:fk__referenced_object_id).as(:schema),
+ object_name(:fk__referenced_object_id).as(:table)]}.
+ order(:name)
+ h = {}
+ ds.each do |row|
+ if r = h[row[:name]]
+ r[:columns] << m.call(row[:column])
+ r[:key] << m.call(row[:referenced_column])
+ else
+ referenced_schema = m.call(row[:schema])
+ referenced_table = m.call(row[:table])
+ h[row[:name]] = { :name => m.call(row[:name]),
+ :table => (referenced_schema == current_schema) ? referenced_table : :"#{referenced_schema}__#{referenced_table}",
+ :columns => [m.call(row[:column])],
+ :key => [m.call(row[:referenced_column])],
+ :on_update => fk_action_map[row[:update_referential_action]],
+ :on_delete => fk_action_map[row[:delete_referential_action]] }
+ end
+ end
+ h.values
+ end
+
# Use the system tables to get index information
def indexes(table, opts={})
m = output_identifier_meth
View
78 spec/adapters/mssql_spec.rb
@@ -568,3 +568,81 @@ def transaction(opts={})
MSSQL_DB[:test__items].columns.should == [:id]
end
end
+
+describe "Database#foreign_key_list" do
+ before(:all) do
+ MSSQL_DB.create_table! :items do
+ primary_key :id
+ integer :sku
+ end
+ MSSQL_DB.create_table! :prices do
+ integer :item_id
+ datetime :valid_from
+ float :price
+ primary_key [:item_id, :valid_from]
+ foreign_key [:item_id], :items, :key => :id, :name => :fk_prices_items
+ end
+ MSSQL_DB.create_table! :sales do
+ integer :id
+ integer :price_item_id
+ datetime :price_valid_from
+ foreign_key [:price_item_id, :price_valid_from], :prices, :key => [:item_id, :valid_from], :name => :fk_sales_prices, :on_delete => :cascade
+ end
+ end
+ after(:all) do
+ MSSQL_DB.drop_table :sales
+ MSSQL_DB.drop_table :prices
+ MSSQL_DB.drop_table :items
+ end
+ it "should support typical foreign keys" do
+ MSSQL_DB.foreign_key_list(:prices).should == [{:name => :fk_prices_items,
+ :table => :items,
+ :columns => [:item_id],
+ :key => [:id],
+ :on_update => :no_action,
+ :on_delete => :no_action }]
+ end
+ it "should support a foreign key with multiple columns" do
+ MSSQL_DB.foreign_key_list(:sales).should == [{:name => :fk_sales_prices,
+ :table => :prices,
+ :columns => [:price_item_id, :price_valid_from],
+ :key => [:item_id, :valid_from],
+ :on_update => :no_action,
+ :on_delete => :cascade }]
+ end
+
+ context "with multiple schemas" do
+ before(:all) do
+ MSSQL_DB.execute_ddl "create schema vendor"
+ MSSQL_DB.create_table! :vendor__vendors do
+ primary_key :id
+ varchar :name
+ end
+ MSSQL_DB.create_table! :vendor__mapping do
+ integer :vendor_id
+ integer :item_id
+ foreign_key [:vendor_id], :vendor__vendors, :name => :fk_mapping_vendor
+ foreign_key [:item_id], :items, :name => :fk_mapping_item
+ end
+ end
+ after(:all) do
+ MSSQL_DB.drop_table :vendor__mapping
+ MSSQL_DB.drop_table :vendor__vendors
+ MSSQL_DB.execute_ddl "drop schema vendor"
+ end
+ it "should support mixed schema bound tables" do
+ MSSQL_DB.foreign_key_list(:vendor__mapping).should == [{:name => :fk_mapping_item,
+ :table => :items,
+ :columns => [:item_id],
+ :key => [:id],
+ :on_update => :no_action,
+ :on_delete => :no_action },
+ {:name => :fk_mapping_vendor,
+ :table => :vendor__vendors,
+ :columns => [:vendor_id],
+ :key => [:id],
+ :on_update => :no_action,
+ :on_delete => :no_action }]
+ end
+ end
+end
Something went wrong with that request. Please try again.