From 51c0bee90433c8c717f2891eb5c5bcc5c4548323 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Philippe=20L=C3=A9caillon?= Date: Fri, 23 Feb 2018 21:05:29 +0100 Subject: [PATCH] #36 Support to drop temporal tables in SQL Server. --- .../Dialect/SQLServer/SQLServerSchema.cs | 55 ++++++++++++++++--- src/Evolve/Evolve.nuspec | 1 + .../Migration/V2_1__create_table_test.sql | 16 +++++- 3 files changed, 62 insertions(+), 10 deletions(-) diff --git a/src/Evolve/Dialect/SQLServer/SQLServerSchema.cs b/src/Evolve/Dialect/SQLServer/SQLServerSchema.cs index 5dd5c722..cbe5adee 100644 --- a/src/Evolve/Dialect/SQLServer/SQLServerSchema.cs +++ b/src/Evolve/Dialect/SQLServer/SQLServerSchema.cs @@ -1,10 +1,13 @@ -using System.Linq; +using System; +using System.Linq; using Evolve.Connection; namespace Evolve.Dialect.SQLServer { public class SQLServerSchema : Schema { + private long _version = 0; + public SQLServerSchema(string schemaName, WrappedConnection wrappedConnection) : base(schemaName, wrappedConnection) { } @@ -54,11 +57,12 @@ public override bool Erase() DropDefaultConstraints(); DropProcedures(); DropViews(); + DropSystemVersioning(); // SQLServerVersion >= 13 DropTables(); DropFunctions(); DropTypes(); DropSynonyms(); - DropSequences(); // SQLServer >= 11 + DropSequences(); // SQLServerVersion >= 11 return true; } @@ -108,6 +112,25 @@ protected void DropViews() }); } + private void DropSystemVersioning() + { + if (SQLServerVersion < 13) + { + return; + } + + string sql = "SELECT t.name as TABLE_NAME " + + "FROM sys.tables t " + + "INNER JOIN sys.schemas s ON s.schema_id = t.schema_id " + + $"WHERE s.name = '{Name}' " + + "AND t.temporal_type = 2"; + + _wrappedConnection.QueryForListOfString(sql).ToList().ForEach(table => + { + _wrappedConnection.ExecuteNonQuery($"ALTER TABLE [{Name}].[{table}] SET (SYSTEM_VERSIONING = OFF)"); + }); + } + protected void DropTables() { string sql = $"SELECT table_name FROM INFORMATION_SCHEMA.TABLES WHERE table_type='BASE TABLE' AND table_schema = '{Name}'"; @@ -146,14 +169,10 @@ protected void DropSynonyms() protected void DropSequences() { - string sqlversion = "SELECT CAST (CASE WHEN CAST(SERVERPROPERTY ('productversion') as VARCHAR) LIKE '8%' THEN 8 " + - "WHEN CAST(SERVERPROPERTY ('productversion') as VARCHAR) LIKE '9%' THEN 9 " + - "WHEN CAST(SERVERPROPERTY ('productversion') as VARCHAR) LIKE '10%' THEN 10 " + - "ELSE CAST(LEFT(CAST(SERVERPROPERTY ('productversion') as VARCHAR), 2) as int) " + - "END AS int)"; - - if (_wrappedConnection.QueryForLong(sqlversion) < 11) + if (SQLServerVersion < 11) + { return; + } string sql = $"SELECT sequence_name FROM INFORMATION_SCHEMA.SEQUENCES WHERE sequence_schema = '{Name}'"; _wrappedConnection.QueryForListOfString(sql).ToList().ForEach(s => @@ -161,5 +180,23 @@ protected void DropSequences() _wrappedConnection.ExecuteNonQuery($"DROP SEQUENCE [{Name}].[{s}]"); }); } + + private long SQLServerVersion + { + get + { + if (_version > 0) + { + return _version; + } + + _version = _wrappedConnection.QueryForLong("SELECT CAST (CASE WHEN CAST(SERVERPROPERTY ('productversion') as VARCHAR) LIKE '8%' THEN 8 " + + "WHEN CAST(SERVERPROPERTY ('productversion') as VARCHAR) LIKE '9%' THEN 9 " + + "WHEN CAST(SERVERPROPERTY ('productversion') as VARCHAR) LIKE '10%' THEN 10 " + + "ELSE CAST(LEFT(CAST(SERVERPROPERTY ('productversion') as VARCHAR), 2) as int) " + + "END AS int)"); + return _version; + } + } } } diff --git a/src/Evolve/Evolve.nuspec b/src/Evolve/Evolve.nuspec index fd509b3f..b5aef85b 100644 --- a/src/Evolve/Evolve.nuspec +++ b/src/Evolve/Evolve.nuspec @@ -15,6 +15,7 @@ Every time you build your project, it will automatically ensure that your databa - Full .NET Core 2.0 support. - Add a new configuration parameter: Evolve.CommandTimeout. - Normalize line endings when calculating checksums. (Thx to @mhelleborg) +- Support to drop temporal tables in SQL Server. - New Cake build script. - Add new Evolve package integration tests. - Fix Linux evolve.json not found for lowercase file name. diff --git a/test/Evolve.IntegrationTest.SQLServer/Resources/Sql_Scripts/Migration/V2_1__create_table_test.sql b/test/Evolve.IntegrationTest.SQLServer/Resources/Sql_Scripts/Migration/V2_1__create_table_test.sql index 870ade60..0f86b2a0 100644 --- a/test/Evolve.IntegrationTest.SQLServer/Resources/Sql_Scripts/Migration/V2_1__create_table_test.sql +++ b/test/Evolve.IntegrationTest.SQLServer/Resources/Sql_Scripts/Migration/V2_1__create_table_test.sql @@ -6,4 +6,18 @@ CREATE TABLE TEST DATE_TEST date NOT NULL, FOREIGN KEY (DATE_TEST) REFERENCES CALENDRIER (JOUR) ON DELETE CASCADE, -) \ No newline at end of file +); + +CREATE TABLE dbo.Employee +( + [EmployeeID] int NOT NULL PRIMARY KEY CLUSTERED + , [Name] nvarchar(100) NOT NULL + , [Position] varchar(100) NOT NULL + , [Department] varchar(100) NOT NULL + , [Address] nvarchar(1024) NOT NULL + , [AnnualSalary] decimal (10,2) NOT NULL + , [ValidFrom] datetime2 (2) GENERATED ALWAYS AS ROW START + , [ValidTo] datetime2 (2) GENERATED ALWAYS AS ROW END + , PERIOD FOR SYSTEM_TIME (ValidFrom, ValidTo) + ) + WITH (SYSTEM_VERSIONING = ON (HISTORY_TABLE = dbo.EmployeeHistory)); \ No newline at end of file