Skip to content

Commit 92ff32a

Browse files
committed
Refactor columns introspection query to make it faster
1 parent b833393 commit 92ff32a

File tree

3 files changed

+72
-49
lines changed

3 files changed

+72
-49
lines changed

Diff for: lib/active_record/connection_adapters/sqlserver/schema_statements.rb

+70-49
Original file line numberDiff line numberDiff line change
@@ -343,55 +343,9 @@ def column_definitions(table_name)
343343
database = identifier.fully_qualified_database_quoted
344344
view_exists = view_exists?(table_name)
345345
view_tblnm = view_table_name(table_name) if view_exists
346-
sql = %{
347-
SELECT DISTINCT
348-
#{lowercase_schema_reflection_sql('columns.TABLE_NAME')} AS table_name,
349-
#{lowercase_schema_reflection_sql('columns.COLUMN_NAME')} AS name,
350-
columns.DATA_TYPE AS type,
351-
columns.COLUMN_DEFAULT AS default_value,
352-
columns.NUMERIC_SCALE AS numeric_scale,
353-
columns.NUMERIC_PRECISION AS numeric_precision,
354-
columns.DATETIME_PRECISION AS datetime_precision,
355-
columns.COLLATION_NAME AS [collation],
356-
columns.ordinal_position,
357-
CASE
358-
WHEN columns.DATA_TYPE IN ('nchar','nvarchar','char','varchar') THEN columns.CHARACTER_MAXIMUM_LENGTH
359-
ELSE COL_LENGTH('#{database}.'+columns.TABLE_SCHEMA+'.'+columns.TABLE_NAME, columns.COLUMN_NAME)
360-
END AS [length],
361-
CASE
362-
WHEN columns.IS_NULLABLE = 'YES' THEN 1
363-
ELSE NULL
364-
END AS [is_nullable],
365-
CASE
366-
WHEN KCU.COLUMN_NAME IS NOT NULL AND TC.CONSTRAINT_TYPE = N'PRIMARY KEY' THEN 1
367-
ELSE NULL
368-
END AS [is_primary],
369-
c.is_identity AS [is_identity]
370-
FROM #{database}.INFORMATION_SCHEMA.COLUMNS columns
371-
LEFT OUTER JOIN #{database}.INFORMATION_SCHEMA.TABLE_CONSTRAINTS AS TC
372-
ON TC.TABLE_NAME = columns.TABLE_NAME
373-
AND TC.TABLE_SCHEMA = columns.TABLE_SCHEMA
374-
AND TC.CONSTRAINT_TYPE = N'PRIMARY KEY'
375-
LEFT OUTER JOIN #{database}.INFORMATION_SCHEMA.KEY_COLUMN_USAGE AS KCU
376-
ON KCU.COLUMN_NAME = columns.COLUMN_NAME
377-
AND KCU.CONSTRAINT_NAME = TC.CONSTRAINT_NAME
378-
AND KCU.CONSTRAINT_CATALOG = TC.CONSTRAINT_CATALOG
379-
AND KCU.CONSTRAINT_SCHEMA = TC.CONSTRAINT_SCHEMA
380-
INNER JOIN #{database}.sys.schemas AS s
381-
ON s.name = columns.TABLE_SCHEMA
382-
AND s.schema_id = s.schema_id
383-
INNER JOIN #{database}.sys.objects AS o
384-
ON s.schema_id = o.schema_id
385-
AND o.is_ms_shipped = 0
386-
AND o.type IN ('U', 'V')
387-
AND o.name = columns.TABLE_NAME
388-
INNER JOIN #{database}.sys.columns AS c
389-
ON o.object_id = c.object_id
390-
AND c.name = columns.COLUMN_NAME
391-
WHERE columns.TABLE_NAME = #{prepared_statements ? '@0' : quote(identifier.object)}
392-
AND columns.TABLE_SCHEMA = #{identifier.schema.blank? ? 'schema_name()' : (prepared_statements ? '@1' : quote(identifier.schema))}
393-
ORDER BY columns.ordinal_position
394-
}.gsub(/[ \t\r\n]+/, ' ').strip
346+
347+
sql = column_definitions_sql(database, identifier)
348+
395349
binds = []
396350
nv128 = SQLServer::Type::UnicodeVarchar.new limit: 128
397351
binds << Relation::QueryAttribute.new('TABLE_NAME', identifier.object, nv128)
@@ -458,6 +412,73 @@ def column_definitions(table_name)
458412
end
459413
end
460414

415+
def column_definitions_sql(database, identifier)
416+
object_name = prepared_statements ? '@0' : quote(identifier.object)
417+
schema_name = if identifier.schema.blank?
418+
'schema_name()'
419+
else
420+
prepared_statements ? '@1' : quote(identifier.schema)
421+
end
422+
423+
%{
424+
SELECT
425+
#{lowercase_schema_reflection_sql('o.name')} AS [table_name],
426+
#{lowercase_schema_reflection_sql('c.name')} AS [name],
427+
t.name AS [type],
428+
d.definition AS [default_value],
429+
CASE
430+
WHEN t.name IN ('decimal', 'bigint', 'int', 'money', 'numeric', 'smallint', 'smallmoney', 'tinyint')
431+
THEN c.scale
432+
END AS [numeric_scale],
433+
CASE
434+
WHEN t.name IN ('decimal', 'bigint', 'int', 'money', 'numeric', 'smallint', 'smallmoney', 'tinyint', 'real', 'float')
435+
THEN c.precision
436+
END AS [numeric_precision],
437+
CASE
438+
WHEN t.name IN ('date', 'datetime', 'datetime2', 'datetimeoffset', 'smalldatetime', 'time')
439+
THEN c.scale
440+
END AS [datetime_precision],
441+
c.collation_name AS [collation],
442+
ROW_NUMBER() OVER (ORDER BY c.column_id) AS [ordinal_position],
443+
CASE
444+
WHEN t.name IN ('nchar', 'nvarchar') AND c.max_length > 0
445+
THEN c.max_length / 2
446+
ELSE c.max_length
447+
END AS [length],
448+
CASE c.is_nullable
449+
WHEN 1
450+
THEN 1
451+
END AS [is_nullable],
452+
CASE
453+
WHEN ic.object_id IS NOT NULL
454+
THEN 1
455+
END AS [is_primary],
456+
c.is_identity AS [is_identity]
457+
FROM #{database}.sys.columns c
458+
INNER JOIN #{database}.sys.objects o
459+
ON c.object_id = o.object_id
460+
INNER JOIN #{database}.sys.schemas s
461+
ON o.schema_id = s.schema_id
462+
INNER JOIN #{database}.sys.types t
463+
ON c.system_type_id = t.system_type_id
464+
AND c.user_type_id = t.user_type_id
465+
LEFT OUTER JOIN #{database}.sys.default_constraints d
466+
ON c.object_id = d.parent_object_id
467+
AND c.default_object_id = d.object_id
468+
LEFT OUTER JOIN #{database}.sys.key_constraints k
469+
ON c.object_id = k.parent_object_id
470+
LEFT OUTER JOIN #{database}.sys.index_columns ic
471+
ON k.parent_object_id = ic.object_id
472+
AND k.unique_index_id = ic.index_id
473+
AND c.column_id = ic.column_id
474+
WHERE
475+
o.name = #{object_name}
476+
AND s.name = #{schema_name}
477+
ORDER BY
478+
c.column_id
479+
}.gsub(/[ \t\r\n]+/, ' ').strip
480+
end
481+
461482
def remove_check_constraints(table_name, column_name)
462483
constraints = select_values "SELECT CONSTRAINT_NAME FROM INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE where TABLE_NAME = '#{quote_string(table_name)}' and COLUMN_NAME = '#{quote_string(column_name)}'", 'SCHEMA'
463484
constraints.each do |constraint|

Diff for: test/support/core_ext/query_cache.rb

+1
Original file line numberDiff line numberDiff line change
@@ -5,6 +5,7 @@ module SqlIgnoredCache
55

66
IGNORED_SQL = [
77
/INFORMATION_SCHEMA\.(TABLES|VIEWS|COLUMNS|KEY_COLUMN_USAGE)/im,
8+
/sys.columns/i,
89
/SELECT @@version/,
910
/SELECT @@TRANCOUNT/,
1011
/(BEGIN|COMMIT|ROLLBACK|SAVE) TRANSACTION/,

Diff for: test/support/sql_counter_sqlserver.rb

+1
Original file line numberDiff line numberDiff line change
@@ -14,6 +14,7 @@ def capture_sql_ss
1414

1515
ignored_sql = [
1616
/INFORMATION_SCHEMA\.(TABLES|VIEWS|COLUMNS|KEY_COLUMN_USAGE)/im,
17+
/sys.columns/i,
1718
/SELECT @@version/,
1819
/SELECT @@TRANCOUNT/,
1920
/(BEGIN|COMMIT|ROLLBACK|SAVE) TRANSACTION/,

0 commit comments

Comments
 (0)