Skip to content
This repository

HTTPS clone URL

Subversion checkout URL

You can clone with HTTPS or Subversion.

Download ZIP

Add MSSQL support for Database#foreign_key_list #564

Merged
merged 1 commit into from over 1 year ago

3 participants

Mike Luu Jeremy Evans rohitn
Mike Luu

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.

Jeremy Evans
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
Mike Luu

@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.

Jeremy Evans jeremyevans merged commit 4f30f84 into from
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment

Showing 1 unique commit by 1 author.

Oct 02, 2012
mluu Add MSSQL support for Database#foreign_key_list 4f30f84
This page is out of date. Refresh to see the latest.
42 lib/sequel/adapters/shared/mssql.rb
@@ -13,6 +13,7 @@ module DatabaseMethods
13 13 SQL_ROLLBACK_TO_SAVEPOINT = 'IF @@TRANCOUNT > 0 ROLLBACK TRANSACTION autopoint_%d'.freeze
14 14 SQL_SAVEPOINT = 'SAVE TRANSACTION autopoint_%d'.freeze
15 15 MSSQL_DEFAULT_RE = /\A(?:\(N?('.*')\)|\(\((-?\d+(?:\.\d+)?)\)\))\z/
  16 + FOREIGN_KEY_ACTION_MAP = {0 => :no_action, 1 => :cascade, 2 => :set_null, 3 => :set_default}.freeze
16 17
17 18 include Sequel::Database::SplitAlterTable
18 19
@@ -36,6 +37,47 @@ def global_index_namespace?
36 37 false
37 38 end
38 39
  40 + # Return foreign key information using the system views, including
  41 + # :name, :on_delete, and :on_update entries in the hashes.
  42 + def foreign_key_list(table, opts={})
  43 + m = output_identifier_meth
  44 + im = input_identifier_meth
  45 + schema, table = schema_and_table(table)
  46 + current_schema = m.call(get(Sequel.function('schema_name')))
  47 + fk_action_map = FOREIGN_KEY_ACTION_MAP
  48 + ds = metadata_dataset.from(:sys__foreign_keys___fk).
  49 + join(:sys__foreign_key_columns___fkc, :constraint_object_id => :object_id).
  50 + join(:sys__all_columns___pc, :object_id => :fkc__parent_object_id, :column_id => :fkc__parent_column_id).
  51 + join(:sys__all_columns___rc, :object_id => :fkc__referenced_object_id, :column_id => :fkc__referenced_column_id).
  52 + where{{object_schema_name(:fk__parent_object_id) => im.call(schema || current_schema)}}.
  53 + where{{object_name(:fk__parent_object_id) => im.call(table)}}.
  54 + select{[:fk__name,
  55 + :fk__delete_referential_action,
  56 + :fk__update_referential_action,
  57 + :pc__name___column,
  58 + :rc__name___referenced_column,
  59 + object_schema_name(:fk__referenced_object_id).as(:schema),
  60 + object_name(:fk__referenced_object_id).as(:table)]}.
  61 + order(:name)
  62 + h = {}
  63 + ds.each do |row|
  64 + if r = h[row[:name]]
  65 + r[:columns] << m.call(row[:column])
  66 + r[:key] << m.call(row[:referenced_column])
  67 + else
  68 + referenced_schema = m.call(row[:schema])
  69 + referenced_table = m.call(row[:table])
  70 + h[row[:name]] = { :name => m.call(row[:name]),
  71 + :table => (referenced_schema == current_schema) ? referenced_table : :"#{referenced_schema}__#{referenced_table}",
  72 + :columns => [m.call(row[:column])],
  73 + :key => [m.call(row[:referenced_column])],
  74 + :on_update => fk_action_map[row[:update_referential_action]],
  75 + :on_delete => fk_action_map[row[:delete_referential_action]] }
  76 + end
  77 + end
  78 + h.values
  79 + end
  80 +
39 81 # Use the system tables to get index information
40 82 def indexes(table, opts={})
41 83 m = output_identifier_meth
78 spec/adapters/mssql_spec.rb
@@ -568,3 +568,81 @@ def transaction(opts={})
568 568 MSSQL_DB[:test__items].columns.should == [:id]
569 569 end
570 570 end
  571 +
  572 +describe "Database#foreign_key_list" do
  573 + before(:all) do
  574 + MSSQL_DB.create_table! :items do
  575 + primary_key :id
  576 + integer :sku
  577 + end
  578 + MSSQL_DB.create_table! :prices do
  579 + integer :item_id
  580 + datetime :valid_from
  581 + float :price
  582 + primary_key [:item_id, :valid_from]
  583 + foreign_key [:item_id], :items, :key => :id, :name => :fk_prices_items
  584 + end
  585 + MSSQL_DB.create_table! :sales do
  586 + integer :id
  587 + integer :price_item_id
  588 + datetime :price_valid_from
  589 + foreign_key [:price_item_id, :price_valid_from], :prices, :key => [:item_id, :valid_from], :name => :fk_sales_prices, :on_delete => :cascade
  590 + end
  591 + end
  592 + after(:all) do
  593 + MSSQL_DB.drop_table :sales
  594 + MSSQL_DB.drop_table :prices
  595 + MSSQL_DB.drop_table :items
  596 + end
  597 + it "should support typical foreign keys" do
  598 + MSSQL_DB.foreign_key_list(:prices).should == [{:name => :fk_prices_items,
  599 + :table => :items,
  600 + :columns => [:item_id],
  601 + :key => [:id],
  602 + :on_update => :no_action,
  603 + :on_delete => :no_action }]
  604 + end
  605 + it "should support a foreign key with multiple columns" do
  606 + MSSQL_DB.foreign_key_list(:sales).should == [{:name => :fk_sales_prices,
  607 + :table => :prices,
  608 + :columns => [:price_item_id, :price_valid_from],
  609 + :key => [:item_id, :valid_from],
  610 + :on_update => :no_action,
  611 + :on_delete => :cascade }]
  612 + end
  613 +
  614 + context "with multiple schemas" do
  615 + before(:all) do
  616 + MSSQL_DB.execute_ddl "create schema vendor"
  617 + MSSQL_DB.create_table! :vendor__vendors do
  618 + primary_key :id
  619 + varchar :name
  620 + end
  621 + MSSQL_DB.create_table! :vendor__mapping do
  622 + integer :vendor_id
  623 + integer :item_id
  624 + foreign_key [:vendor_id], :vendor__vendors, :name => :fk_mapping_vendor
  625 + foreign_key [:item_id], :items, :name => :fk_mapping_item
  626 + end
  627 + end
  628 + after(:all) do
  629 + MSSQL_DB.drop_table :vendor__mapping
  630 + MSSQL_DB.drop_table :vendor__vendors
  631 + MSSQL_DB.execute_ddl "drop schema vendor"
  632 + end
  633 + it "should support mixed schema bound tables" do
  634 + MSSQL_DB.foreign_key_list(:vendor__mapping).should == [{:name => :fk_mapping_item,
  635 + :table => :items,
  636 + :columns => [:item_id],
  637 + :key => [:id],
  638 + :on_update => :no_action,
  639 + :on_delete => :no_action },
  640 + {:name => :fk_mapping_vendor,
  641 + :table => :vendor__vendors,
  642 + :columns => [:vendor_id],
  643 + :key => [:id],
  644 + :on_update => :no_action,
  645 + :on_delete => :no_action }]
  646 + end
  647 + end
  648 +end

Tip: You can add notes to lines in a file. Hover to the left of a line to make a note

Something went wrong with that request. Please try again.