From 29bc055553247b44ace564c62acd5e05509438e5 Mon Sep 17 00:00:00 2001 From: Karl Southern <karl@theangryangel.co.uk> Date: Mon, 20 Apr 2015 11:23:42 +0100 Subject: [PATCH 1/2] Adds simple batched support --- .../tasks/sqlserver_database_tasks.rb | 18 +++++++++++++++--- 1 file changed, 15 insertions(+), 3 deletions(-) diff --git a/lib/active_record/tasks/sqlserver_database_tasks.rb b/lib/active_record/tasks/sqlserver_database_tasks.rb index 57dedbd50..fc30f1d4d 100644 --- a/lib/active_record/tasks/sqlserver_database_tasks.rb +++ b/lib/active_record/tasks/sqlserver_database_tasks.rb @@ -59,8 +59,6 @@ def structure_dump(filename) ] table_args = connection.tables.map { |t| Shellwords.escape(t) } command.concat(table_args) - view_args = connection.views.map { |v| Shellwords.escape(v) } - command.concat(view_args) raise 'Error dumping database' unless Kernel.system(command.join(' ')) dump = File.read(filename) dump.gsub!(/^USE .*$\nGO\n/, '') # Strip db USE statements @@ -69,10 +67,24 @@ def structure_dump(filename) dump.gsub!(/nvarchar\(-1\)/, 'nvarchar(max)') # Fix nvarchar(-1) column defs dump.gsub!(/text\(\d+\)/, 'text') # Fix text(16) column defs File.open(filename, "w") { |file| file.puts dump } + + # defncopy appears to truncate definition output in some circumstances + # Also create view needs to be the first operation in the batch. + File.open(filename, 'a') { |file| + connection.select_all("select definition, o.type from sys.objects as o join sys.sql_modules as m on m.object_id = o.object_id where o.type = 'V'").each do |row| + file.puts "\r\nGO\r\n#{row['definition']}" + end + file.puts "\r\nGO\r\n" + } end def structure_load(filename) - connection.execute File.read(filename) + structure = File.read(filename) + # Split by GO so that operations that must be in separate batches are in + # separate batches + structure.split(/^GO/).each { |s| + connection.execute s + } end From d7855ac8a610c1dd095292fbbbc8c1e16b782fae Mon Sep 17 00:00:00 2001 From: Karl Southern <karl@theangryangel.co.uk> Date: Fri, 29 May 2015 18:37:05 +0100 Subject: [PATCH 2/2] Switches to view_information, and adds routine_information. Adds a few simple tests to ensure that they are all working as expected. --- .gitignore | 4 +++- .../sqlserver/schema_statements.rb | 20 ++++++++++++++++++ .../tasks/sqlserver_database_tasks.rb | 13 ++++++++++-- test/cases/adapter_test_sqlserver.rb | 19 +++++++++++++++++ test/cases/rake_test_sqlserver.rb | 21 ++++++++++++++++++- test/schema/sqlserver_specific_schema.rb | 18 ++++++++++++++++ 6 files changed, 91 insertions(+), 4 deletions(-) diff --git a/.gitignore b/.gitignore index 511d7d68d..a22d8f6b9 100644 --- a/.gitignore +++ b/.gitignore @@ -12,4 +12,6 @@ test/profile/output/* .idea coverage/* .flooignore -.floo \ No newline at end of file +.floo +.vagrant/ +Vagrantfile diff --git a/lib/active_record/connection_adapters/sqlserver/schema_statements.rb b/lib/active_record/connection_adapters/sqlserver/schema_statements.rb index e2a9a9764..030b9e4c0 100644 --- a/lib/active_record/connection_adapters/sqlserver/schema_statements.rb +++ b/lib/active_record/connection_adapters/sqlserver/schema_statements.rb @@ -442,6 +442,26 @@ def identity_column(table_name) schema_cache.columns(table_name).find(&:is_identity?) end + # === SQLServer Specific (Stored Rrocedure Reflection) ====================== # + + def routines(routine_type = nil) + select_values "SELECT #{lowercase_schema_reflection_sql('ROUTINE_NAME')} FROM INFORMATION_SCHEMA.ROUTINES #{"WHERE ROUTINE_TYPE = '#{routine_type}'" if routine_type} ORDER BY ROUTINE_NAME", 'SCHEMA' + end + + def routine_information(routine_name) + identifier = SQLServer::Utils.extract_identifiers(routine_name) + routine_info = select_one "SELECT * FROM information_schema.routines WHERE ROUTINE_NAME = '#{identifier.object}'", 'SCHEMA' + + if routine_info + routine_info = routine_info.with_indifferent_access + if routine_info[:ROUTINE_DEFINITION].blank? + warn "No routing definition found, possible permissions problem.\nPlease run GRANT VIEW DEFINITION TO your_user;" + nil + else + routine_info + end + end + end private diff --git a/lib/active_record/tasks/sqlserver_database_tasks.rb b/lib/active_record/tasks/sqlserver_database_tasks.rb index fc30f1d4d..0291338dd 100644 --- a/lib/active_record/tasks/sqlserver_database_tasks.rb +++ b/lib/active_record/tasks/sqlserver_database_tasks.rb @@ -71,8 +71,17 @@ def structure_dump(filename) # defncopy appears to truncate definition output in some circumstances # Also create view needs to be the first operation in the batch. File.open(filename, 'a') { |file| - connection.select_all("select definition, o.type from sys.objects as o join sys.sql_modules as m on m.object_id = o.object_id where o.type = 'V'").each do |row| - file.puts "\r\nGO\r\n#{row['definition']}" + connection.send(:views).each do |v| + view_info = connection.send(:view_information, v) + file.puts "\r\nGO\r\n#{view_info[:VIEW_DEFINITION]}" + end + } + + # Export any routines (stored procedures, functions, etc.) + File.open(filename, 'a') { |file| + connection.send(:routines).each do |r| + routine_info = connection.send(:routine_information, r) + file.puts "\r\nGO\r\n#{routine_info[:ROUTINE_DEFINITION]}" end file.puts "\r\nGO\r\n" } diff --git a/test/cases/adapter_test_sqlserver.rb b/test/cases/adapter_test_sqlserver.rb index ba9e0a915..1243201ef 100644 --- a/test/cases/adapter_test_sqlserver.rb +++ b/test/cases/adapter_test_sqlserver.rb @@ -416,5 +416,24 @@ class AdapterTestSQLServer < ActiveRecord::TestCase end + + describe 'routines' do + + it 'return an array' do + assert_instance_of Array, connection.send(:routines) + end + + it 'sst_routines_1 routine must exist' do + connection.send(:routines).must_include 'sst_routine_1' + end + + it 'allow the connection#routine_information method to return data on the routine' do + routine_info = connection.send(:routine_information,'sst_routine_2') + assert_equal('sst_routine_2', routine_info['ROUTINE_NAME']) + assert_match(/CREATE FUNCTION sst_routine_2/, routine_info['ROUTINE_DEFINITION']) + end + + end + end diff --git a/test/cases/rake_test_sqlserver.rb b/test/cases/rake_test_sqlserver.rb index 19de32a0f..cd7b995f4 100644 --- a/test/cases/rake_test_sqlserver.rb +++ b/test/cases/rake_test_sqlserver.rb @@ -113,6 +113,16 @@ class SQLServerRakeStructureDumpLoadTest < SQLServerRakeTest t.text_basic :background2 t.timestamps null: false end + + connection.execute <<-CUSTOMERSVIEW + CREATE VIEW users_view AS + SELECT name FROM users + CUSTOMERSVIEW + + connection.execute <<-PROCEDUREDEF + CREATE PROCEDURE users_procedure AS + SELECT 1 + PROCEDUREDEF end after do @@ -122,7 +132,6 @@ class SQLServerRakeStructureDumpLoadTest < SQLServerRakeTest it 'dumps structure and accounts for defncopy oddities' do db_tasks.structure_dump configuration, filename filedata.wont_match %r{\AUSE.*\z} - filedata.wont_match %r{\AGO.*\z} filedata.must_match %r{email\s+nvarchar\(4000\)} filedata.must_match %r{background1\s+nvarchar\(max\)} filedata.must_match %r{background2\s+text\s+} @@ -130,11 +139,21 @@ class SQLServerRakeStructureDumpLoadTest < SQLServerRakeTest it 'can load dumped structure' do db_tasks.structure_dump configuration, filename + filedata.must_match %r{CREATE TABLE dbo\.users} + filedata.must_match %r{CREATE PROCEDURE users_procedure} + filedata.must_match %r{CREATE VIEW users_view} + db_tasks.purge(configuration) connection.tables.wont_include 'users' + connection.send(:routines).wont_include 'users_procedure' + connection.send(:views).wont_include 'users_view' + db_tasks.load_schema_for configuration, :sql, filename + connection.tables.must_include 'users' + connection.send(:routines).must_include 'users_procedure' + connection.send(:views).must_include 'users_view' end end diff --git a/test/schema/sqlserver_specific_schema.rb b/test/schema/sqlserver_specific_schema.rb index 486952a99..8f33aebc6 100644 --- a/test/schema/sqlserver_specific_schema.rb +++ b/test/schema/sqlserver_specific_schema.rb @@ -144,6 +144,24 @@ FROM sst_string_defaults STRINGDEFAULTSBIGVIEW + # Routines + + execute "IF EXISTS (SELECT ROUTINE_NAME FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'sst_routine_1') DROP PROCEDURE sst_routine_1" + execute <<-PROCEDUREDEF + CREATE PROCEDURE sst_routine_1 AS + SELECT 1 + PROCEDUREDEF + + execute "IF EXISTS (SELECT ROUTINE_NAME FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'sst_routine_2') DROP FUNCTION sst_routine_2" + execute <<-FUNCDEF + CREATE FUNCTION sst_routine_2 () + RETURNS int + AS + BEGIN + RETURN 1 + END + FUNCDEF + # Another schema. create_table :sst_schema_columns, force: true do |t|