Skip to content

Commit 3e7b544

Browse files
committed
Schema reflection now finds primary key for all occasions. Fixed #60 [Boško Ivanišević]
1 parent 4f9e9af commit 3e7b544

File tree

7 files changed

+77
-21
lines changed

7 files changed

+77
-21
lines changed

CHANGELOG

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,8 @@
11

22
* 3.1.0 *
33

4+
* Schema reflection now finds primary key for all occasions. Fixed #60 [Boško Ivanišević]
5+
46
* Allow complex order objects to not be molested by our visitor overrides. Fixes #99
57

68
* Default unicode datatypes!

lib/active_record/connection_adapters/sqlserver/schema_statements.rb

Lines changed: 23 additions & 12 deletions
Original file line numberDiff line numberDiff line change
@@ -7,15 +7,20 @@ def native_database_types
77
@native_database_types ||= initialize_native_database_types.freeze
88
end
99

10-
def tables(name = nil)
10+
def tables(name = nil, schema = nil)
1111
info_schema_query do
12-
select_values "SELECT #{lowercase_schema_reflection_sql('TABLE_NAME')} FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME <> 'dtproperties' AND TABLE_SCHEMA = schema_name()"
12+
select_values "SELECT #{lowercase_schema_reflection_sql('TABLE_NAME')} FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_NAME <> 'dtproperties' AND TABLE_SCHEMA = #{schema.blank? ? "schema_name()" : "#{quote(schema)}"}"
1313
end
1414
end
15+
16+
def tables_in_schema(table_schema)
17+
table_schema.blank? ? [] : tables(nil,table_schema)
18+
end
1519

1620
def table_exists?(table_name)
21+
table_schema = unqualify_table_schema(table_name)
1722
unquoted_table_name = unqualify_table_name(table_name)
18-
super || tables.include?(unquoted_table_name) || views.include?(unquoted_table_name)
23+
super || tables.include?(unquoted_table_name) || views.include?(unquoted_table_name) || tables_in_schema(table_schema).include?(unquoted_table_name)
1924
end
2025

2126
def indexes(table_name, name = nil)
@@ -150,36 +155,41 @@ def initialize_native_database_types
150155
:ss_timestamp => { :name => 'timestamp' }
151156
}
152157
end
153-
158+
154159
def column_definitions(table_name)
155160
db_name = unqualify_db_name(table_name)
156161
db_name_with_period = "#{db_name}." if db_name
157162
table_schema = unqualify_table_schema(table_name)
158163
table_name = unqualify_table_name(table_name)
159164
sql = %{
160-
SELECT
165+
SELECT DISTINCT
161166
#{lowercase_schema_reflection_sql('columns.TABLE_NAME')} AS table_name,
162167
#{lowercase_schema_reflection_sql('columns.COLUMN_NAME')} AS name,
163168
columns.DATA_TYPE AS type,
164169
columns.COLUMN_DEFAULT AS default_value,
165170
columns.NUMERIC_SCALE AS numeric_scale,
166171
columns.NUMERIC_PRECISION AS numeric_precision,
172+
columns.ordinal_position,
167173
CASE
168174
WHEN columns.DATA_TYPE IN ('nchar','nvarchar') THEN columns.CHARACTER_MAXIMUM_LENGTH
169175
ELSE COL_LENGTH(columns.TABLE_SCHEMA+'.'+columns.TABLE_NAME, columns.COLUMN_NAME)
170-
END AS length,
176+
END AS [length],
171177
CASE
172178
WHEN columns.IS_NULLABLE = 'YES' THEN 1
173179
ELSE NULL
174-
END AS is_nullable,
175-
CASE
176-
WHEN COLUMNPROPERTY(OBJECT_ID(columns.TABLE_SCHEMA+'.'+columns.TABLE_NAME), columns.COLUMN_NAME, 'IsIdentity') = 0 THEN NULL
177-
ELSE 1
178-
END AS is_identity
180+
END AS [is_nullable],
181+
CASE
182+
WHEN CCU.COLUMN_NAME IS NOT NULL AND TC.CONSTRAINT_TYPE = N'PRIMARY KEY' THEN 1
183+
WHEN COLUMNPROPERTY(OBJECT_ID(columns.TABLE_SCHEMA+'.'+columns.TABLE_NAME), columns.COLUMN_NAME, 'IsIdentity') = 1 THEN 1
184+
ELSE NULL
185+
END AS [is_identity]
179186
FROM #{db_name_with_period}INFORMATION_SCHEMA.COLUMNS columns
187+
LEFT OUTER JOIN #{db_name_with_period}INFORMATION_SCHEMA.TABLE_CONSTRAINTS AS TC ON TC.TABLE_NAME = columns.TABLE_NAME AND TC.CONSTRAINT_TYPE = N'PRIMARY KEY'
188+
LEFT OUTER JOIN #{db_name_with_period}INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE AS CCU ON TC.CONSTRAINT_NAME = CCU.CONSTRAINT_NAME AND CCU.COLUMN_NAME = columns.COLUMN_NAME
180189
WHERE columns.TABLE_NAME = @0
181190
AND columns.TABLE_SCHEMA = #{table_schema.blank? ? "schema_name()" : "@1"}
182191
ORDER BY columns.ordinal_position
192+
183193
}.gsub(/[ \t\r\n]+/,' ')
184194
binds = [['table_name', table_name]]
185195
binds << ['table_schema',table_schema] unless table_schema.blank?
@@ -213,6 +223,7 @@ def column_definitions(table_name)
213223
match_data ? match_data[1] : nil
214224
end
215225
ci[:null] = ci[:is_nullable].to_i == 1 ; ci.delete(:is_nullable)
226+
ci[:is_identity] = ci[:is_identity].to_i == 1
216227
ci
217228
end
218229
end
@@ -361,7 +372,7 @@ def set_identity_insert(table_name, enable = true)
361372
end
362373

363374
def identity_column(table_name)
364-
columns(table_name).detect(&:is_identity?)
375+
columns(table_name).detect(&:primary) || columns(table_name).detect(&:is_identity?)
365376
end
366377

367378
end

lib/active_record/connection_adapters/sqlserver_adapter.rb

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -55,6 +55,7 @@ class SQLServerColumn < Column
5555
def initialize(name, default, sql_type = nil, null = true, sqlserver_options = {})
5656
@sqlserver_options = sqlserver_options.symbolize_keys
5757
super(name, default, sql_type, null)
58+
@primary = @sqlserver_options[:is_identity]
5859
end
5960

6061
class << self

test/cases/adapter_test_sqlserver.rb

Lines changed: 0 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -540,7 +540,6 @@ def setup
540540

541541
should 'find identity column' do
542542
assert CustomersView.columns_hash['id'].primary
543-
assert CustomersView.columns_hash['id'].is_identity?
544543
end
545544

546545
should 'find default values' do
@@ -573,7 +572,6 @@ def setup
573572

574573
should 'find identity column' do
575574
assert StringDefaultsView.columns_hash['id'].primary
576-
assert StringDefaultsView.columns_hash['id'].is_identity?
577575
end
578576

579577
should 'find default values' do

test/cases/schema_test_sqlserver.rb

Lines changed: 25 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -10,12 +10,31 @@ def read_schema_name(table_name)
1010
@connection.instance_eval { unqualify_table_schema(table_name) }
1111
end
1212

13+
context 'When table is dbo schema' do
14+
15+
should 'find primary key for tables with odd schema' do
16+
assert_equal 'legacy_id', @connection.primary_key('natural_pk_data')
17+
assert SqlServerNaturalPkData.columns_hash['legacy_id'].primary
18+
end
19+
20+
end
21+
1322
context 'When table is in non-dbo schema' do
1423

24+
should 'work with #table_exists?' do
25+
assert @connection.tables_in_schema('test').include?('sql_server_schema_natural_id')
26+
assert @connection.table_exists?('test.sql_server_schema_natural_id')
27+
end
28+
29+
should 'find primary key for tables with odd schema' do
30+
assert_equal 'legacy_id', @connection.primary_key('test.sql_server_schema_natural_id')
31+
assert SqlServerNaturalPkDataSchema.columns_hash['legacy_id'].primary
32+
end
33+
1534
should "have only one identity column" do
1635
columns = @connection.columns("test.sql_server_schema_identity")
1736
assert_equal 2, columns.size
18-
assert_equal 1, columns.select{|column| column.is_identity? }.size
37+
assert_equal 1, columns.select{ |c| c.primary }.size
1938
end
2039

2140
should "read only column properties for table in specific schema" do
@@ -25,9 +44,9 @@ def read_schema_name(table_name)
2544
assert_equal 7, test_columns.size
2645
assert_equal 2, dbo_columns.size
2746
assert_equal 2, columns.size
28-
assert_equal 1, test_columns.select{|column| column.is_identity? }.size
29-
assert_equal 1, dbo_columns.select{|column| column.is_identity? }.size
30-
assert_equal 1, columns.select{|column| column.is_identity? }.size
47+
assert_equal 1, test_columns.select{ |c| c.primary }.size
48+
assert_equal 1, dbo_columns.select{ |c| c.primary }.size
49+
assert_equal 1, columns.select{ |c| c.primary }.size
3150
end
3251

3352
should "return schema name in all cases" do
@@ -47,6 +66,7 @@ def read_schema_name(table_name)
4766
end
4867

4968
end
50-
69+
70+
5171
end
5272

test/cases/sqlserver_helper.rb

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -35,6 +35,8 @@ class NumericData < ActiveRecord::Base ; self.table_name = 'numeric_data' ; end
3535
class CustomersView < ActiveRecord::Base ; self.table_name = 'customers_view' ; end
3636
class StringDefaultsView < ActiveRecord::Base ; self.table_name = 'string_defaults_view' ; end
3737
class StringDefaultsBigView < ActiveRecord::Base ; self.table_name = 'string_defaults_big_view' ; end
38+
class SqlServerNaturalPkData < ActiveRecord::Base ; self.table_name = 'natural_pk_data' ; end
39+
class SqlServerNaturalPkDataSchema < ActiveRecord::Base ; self.table_name = 'test.sql_server_schema_natural_id' ; end
3840
class SqlServerQuotedTable < ActiveRecord::Base ; self.table_name = 'quoted-table' ; end
3941
class SqlServerQuotedView1 < ActiveRecord::Base ; self.table_name = 'quoted-view1' ; end
4042
class SqlServerQuotedView2 < ActiveRecord::Base ; self.table_name = 'quoted-view2' ; end

test/schema/sqlserver_specific_schema.rb

Lines changed: 24 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -71,13 +71,22 @@
7171
t.column :tinyint, :tinyint
7272
t.column :guid, :uniqueidentifier
7373
end
74+
execute %|ALTER TABLE [sql_server_edge_schemas] ADD [guid_newid] uniqueidentifier DEFAULT NEWID();|
75+
execute %|ALTER TABLE [sql_server_edge_schemas] ADD [guid_newseqid] uniqueidentifier DEFAULT NEWSEQUENTIALID();| unless sqlserver_azure?
7476

7577
create_table :no_pk_data, :force => true, :id => false do |t|
7678
t.string :name
7779
end
7880

79-
execute %|ALTER TABLE [sql_server_edge_schemas] ADD [guid_newid] uniqueidentifier DEFAULT NEWID();|
80-
execute %|ALTER TABLE [sql_server_edge_schemas] ADD [guid_newseqid] uniqueidentifier DEFAULT NEWSEQUENTIALID();| unless sqlserver_azure?
81+
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'natural_pk_data') DROP TABLE natural_pk_data"
82+
execute <<-NATURALPKTABLESQL
83+
CREATE TABLE natural_pk_data(
84+
parent_id int,
85+
name nvarchar(255),
86+
description nvarchar(1000),
87+
legacy_id nvarchar(10) NOT NULL PRIMARY KEY,
88+
)
89+
NATURALPKTABLESQL
8190

8291
create_table 'quoted-table', :force => true do |t|
8392
end
@@ -110,9 +119,11 @@
110119

111120

112121
# Another schema.
122+
113123
create_table :sql_server_schema_columns, :force => true do |t|
114124
t.column :field1 , :integer
115125
end
126+
116127
execute "IF NOT EXISTS(SELECT * FROM sys.schemas WHERE name = 'test') EXEC sp_executesql N'CREATE SCHEMA test'"
117128
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sql_server_schema_columns' and TABLE_SCHEMA = 'test') DROP TABLE test.sql_server_schema_columns"
118129
execute <<-SIMILIARTABLEINOTHERSCHEMA
@@ -126,6 +137,7 @@
126137
n_description nvarchar(1000)
127138
)
128139
SIMILIARTABLEINOTHERSCHEMA
140+
129141
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sql_server_schema_identity' and TABLE_SCHEMA = 'test') DROP TABLE test.sql_server_schema_identity"
130142
execute <<-SIMILIARTABLEINOTHERSCHEMA
131143
CREATE TABLE test.sql_server_schema_identity(
@@ -134,6 +146,16 @@
134146
)
135147
SIMILIARTABLEINOTHERSCHEMA
136148

149+
execute "IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'sql_server_schema_natural_id' and TABLE_SCHEMA = 'test') DROP TABLE test.sql_server_schema_natural_id"
150+
execute <<-NATURALPKTABLESQLINOTHERSCHEMA
151+
CREATE TABLE test.sql_server_schema_natural_id(
152+
parent_id int,
153+
name nvarchar(255),
154+
description nvarchar(1000),
155+
legacy_id nvarchar(10) NOT NULL PRIMARY KEY,
156+
)
157+
NATURALPKTABLESQLINOTHERSCHEMA
158+
137159

138160
# Azure needs clustered indexes
139161
if sqlserver_azure?

0 commit comments

Comments
 (0)