diff --git a/model/Database.cs b/model/Database.cs index 24485263..eb361db6 100644 --- a/model/Database.cs +++ b/model/Database.cs @@ -70,7 +70,8 @@ public Database(string name) public List Synonyms = new List(); public List TableTypes = new List
(); public List
Tables = new List
(); - public List Users = new List(); + public List Roles = new List(); + public List Users = new List(); public List ViewIndexes = new List(); public DbProp FindProp(string name) { @@ -102,7 +103,7 @@ public SqlAssembly FindAssembly(string name) { } public SqlUser FindUser(string name) { - return Users.FirstOrDefault(u => u.Name == name); + return Users.FirstOrDefault(u => string.Equals(u.Name, name, StringComparison.CurrentCultureIgnoreCase)); } public Constraint FindViewIndex(string name) { @@ -121,7 +122,7 @@ public List
FindTablesRegEx(string pattern) { private static readonly string[] dirs = { "tables", "foreign_keys", "assemblies", "functions", "procedures", "triggers", - "views", "xmlschemacollections", "data", "users", "synonyms", "table_types" + "views", "xmlschemacollections", "data", "roles", "users", "synonyms", "table_types" }; private void SetPropOnOff(string propName, object dbVal) { @@ -148,6 +149,7 @@ public void Load() { Assemblies.Clear(); Users.Clear(); Synonyms.Clear(); + Roles.Clear(); using (var cn = new SqlConnection(Connection)) { cn.Open(); @@ -167,11 +169,12 @@ public void Load() { LoadCLRAssemblies(cm); LoadUsersAndLogins(cm); LoadSynonyms(cm); - } + LoadRoles(cm); + } } } - private void LoadSynonyms(SqlCommand cm) { + private void LoadSynonyms(SqlCommand cm) { try { // get synonyms cm.CommandText = @" @@ -189,7 +192,124 @@ select object_schema_name(object_id) as schema_name, name as synonym_name, base_ } } - private void LoadUsersAndLogins(SqlCommand cm) { + private void LoadRoles(SqlCommand cm) { + //Roles are complicated. This was adapted from https://dbaeyes.wordpress.com/2013/04/19/fully-script-out-a-mssql-database-role/ + cm.CommandText = @" +create table #ScriptedRoles ( + name nvarchar(255) not null +, script nvarchar(max) +) + +insert into #ScriptedRoles +select + name +, null as script +from sys.database_principals +where type = 'R' + and name not in ( + -- Ignore default roles, just look for custom ones + 'db_accessadmin' + , 'db_backupoperator' + , 'db_datareader' + , 'db_datawriter' + , 'db_ddladmin' + , 'db_denydatareader' + , 'db_denydatawriter' + , 'db_owner' + , 'db_securityadmin' + , 'public' + ) + +while(exists(select 1 from #ScriptedRoles where script is null)) +begin + + DECLARE @RoleName VARCHAR(255) + SET @RoleName = (select top 1 name from #ScriptedRoles where script is null) + + -- Script out the Role + DECLARE @roleDesc VARCHAR(MAX), @crlf VARCHAR(2) + SET @crlf = CHAR(13) + CHAR(10) + SET @roleDesc = 'CREATE ROLE [' + @roleName + ']' + @crlf + 'GO' + @crlf + @crlf + + SELECT @roleDesc = @roleDesc + + CASE dp.state + WHEN 'D' THEN 'DENY ' + WHEN 'G' THEN 'GRANT ' + WHEN 'R' THEN 'REVOKE ' + WHEN 'W' THEN 'GRANT ' + END + + dp.permission_name + ' ' + + CASE dp.class + WHEN 0 THEN '' + WHEN 1 THEN --table or column subset on the table + CASE WHEN dp.major_id < 0 THEN + + 'ON [sys].[' + OBJECT_NAME(dp.major_id) + '] ' + ELSE + + 'ON [' + + (SELECT SCHEMA_NAME(schema_id) + '].[' + name FROM sys.objects WHERE object_id = dp.major_id) + + -- optionally concatenate column names + CASE WHEN MAX(dp.minor_id) > 0 + THEN '] ([' + REPLACE( + (SELECT name + '], [' + FROM sys.columns + WHERE object_id = dp.major_id + AND column_id IN (SELECT minor_id + FROM sys.database_permissions + WHERE major_id = dp.major_id + AND USER_NAME(grantee_principal_id) IN (@roleName) + ) + FOR XML PATH('') + ) --replace final square bracket pair + + '])', ', []', '') + ELSE ']' + END + ' ' + END + WHEN 3 THEN 'ON SCHEMA::[' + SCHEMA_NAME(dp.major_id) + '] ' + WHEN 4 THEN 'ON ' + (SELECT RIGHT(type_desc, 4) + '::[' + name FROM sys.database_principals WHERE principal_id = dp.major_id) + '] ' + WHEN 5 THEN 'ON ASSEMBLY::[' + (SELECT name FROM sys.assemblies WHERE assembly_id = dp.major_id) + '] ' + WHEN 6 THEN 'ON TYPE::[' + (SELECT name FROM sys.types WHERE user_type_id = dp.major_id) + '] ' + WHEN 10 THEN 'ON XML SCHEMA COLLECTION::[' + (SELECT SCHEMA_NAME(schema_id) + '.' + name FROM sys.xml_schema_collections WHERE xml_collection_id = dp.major_id) + '] ' + WHEN 15 THEN 'ON MESSAGE TYPE::[' + (SELECT name FROM sys.service_message_types WHERE message_type_id = dp.major_id) + '] ' + WHEN 16 THEN 'ON CONTRACT::[' + (SELECT name FROM sys.service_contracts WHERE service_contract_id = dp.major_id) + '] ' + WHEN 17 THEN 'ON SERVICE::[' + (SELECT name FROM sys.services WHERE service_id = dp.major_id) + '] ' + WHEN 18 THEN 'ON REMOTE SERVICE BINDING::[' + (SELECT name FROM sys.remote_service_bindings WHERE remote_service_binding_id = dp.major_id) + '] ' + WHEN 19 THEN 'ON ROUTE::[' + (SELECT name FROM sys.routes WHERE route_id = dp.major_id) + '] ' + WHEN 23 THEN 'ON FULLTEXT CATALOG::[' + (SELECT name FROM sys.fulltext_catalogs WHERE fulltext_catalog_id = dp.major_id) + '] ' + WHEN 24 THEN 'ON SYMMETRIC KEY::[' + (SELECT name FROM sys.symmetric_keys WHERE symmetric_key_id = dp.major_id) + '] ' + WHEN 25 THEN 'ON CERTIFICATE::[' + (SELECT name FROM sys.certificates WHERE certificate_id = dp.major_id) + '] ' + WHEN 26 THEN 'ON ASYMMETRIC KEY::[' + (SELECT name FROM sys.asymmetric_keys WHERE asymmetric_key_id = dp.major_id) + '] ' + END COLLATE SQL_Latin1_General_CP1_CI_AS + + 'TO [' + @roleName + ']' + + CASE dp.state WHEN 'W' THEN ' WITH GRANT OPTION' ELSE '' END + @crlf + FROM sys.database_permissions dp + WHERE USER_NAME(dp.grantee_principal_id) IN (@roleName) + GROUP BY dp.state, dp.major_id, dp.permission_name, dp.class + + update #ScriptedRoles + set script = @roleDesc + where name = @RoleName + +end + +select + name +, script +from #ScriptedRoles +"; + Role r = null; + using (var dr = cm.ExecuteReader()) + { + while (dr.Read()) { + r = new Role { + Name = (string) dr["name"], + Script = (string) dr["script"] + }; + Roles.Add(r); + } + } + } + + private void LoadUsersAndLogins(SqlCommand cm) { // get users that have access to the database cm.CommandText = @" select dp.name as UserName, USER_NAME(drm.role_principal_id) as AssociatedDBRole, default_schema_name @@ -480,17 +600,33 @@ from sys.table_types order by s.name, t.name, i.name, ic.key_ordinal, ic.index_column_id"; using (var dr = cm.ExecuteReader()) { while (dr.Read()) { - var t = (string) dr["baseType"] == "V" - ? new Table((string) dr["schemaName"], (string) dr["tableName"]) - : FindTable((string) dr["tableName"], (string) dr["schemaName"], ((string) dr["baseType"]) == "TVT"); - var c = t.FindConstraint((string) dr["indexName"]); - if (c == null) { - c = new Constraint((string) dr["indexName"], "", ""); - t.AddConstraint(c); - - if ((string) dr["baseType"] == "V") - ViewIndexes.Add(c); - } + var schemaName = (string) dr["schemaName"]; + var tableName = (string) dr["tableName"]; + var indexName = (string) dr["indexName"]; + var isView = (string) dr["baseType"] == "V"; + + var t = isView + ? new Table(schemaName, tableName) + : FindTable(tableName, schemaName, (string) dr["baseType"] == "TVT"); + var c = t.FindConstraint( indexName); + + if (c == null) + { + c = new Constraint(indexName, "", ""); + t.AddConstraint(c); + } + + if (isView) + { + if (ViewIndexes.Any(v => v.Name == indexName)) + { + c = ViewIndexes.First(v => v.Name == indexName); + } + else + { + ViewIndexes.Add(c); + } + } c.Clustered = (string) dr["type_desc"] == "CLUSTERED"; c.Unique = (bool) dr["is_unique"]; var filter = dr["filter_definition"].ToString(); //can be null @@ -1043,7 +1179,8 @@ public void ScriptToDir(string tableHint = null, Action log } WriteScriptDir("views", ViewIndexes.ToArray(), log); WriteScriptDir("assemblies", Assemblies.ToArray(), log); - WriteScriptDir("users", Users.ToArray(), log); + WriteScriptDir("roles", Roles.ToArray(), log); + WriteScriptDir("users", Users.ToArray(), log); WriteScriptDir("synonyms", Synonyms.ToArray(), log); ExportData(tableHint, log); @@ -1124,10 +1261,19 @@ public void ExportData(string tableHint = null, Action log = foreach (var t in DataTables) { if (log != null) log(TraceLevel.Verbose, string.Format("Exporting data from {0} (table {1} of {2})...", t.Owner + "." + t.Name, ++index, DataTables.Count)); - var sw = File.CreateText(dataDir + "/" + MakeFileName(t) + ".tsv"); + var filePathAndName = dataDir + "/" + MakeFileName(t) + ".tsv"; + var sw = File.CreateText(filePathAndName); t.ExportData(Connection, sw, tableHint); - sw.Flush(); - sw.Close(); + + sw.Flush(); + if (sw.BaseStream.Length == 0) { + if (log != null) + log(TraceLevel.Verbose, string.Format(" No data to export for {0}, deleting file...", t.Owner + "." + t.Name)); + sw.Close(); + File.Delete(filePathAndName); + } else { + sw.Close(); + } } } diff --git a/model/Role.cs b/model/Role.cs new file mode 100644 index 00000000..512793a1 --- /dev/null +++ b/model/Role.cs @@ -0,0 +1,17 @@ +using System; +using System.Collections.Generic; +using System.Linq; +using System.Text; + +namespace SchemaZen.model +{ + public class Role : IScriptable, INameable + { + public string Name { get; set; } + public string Script { get; set; } + + public string ScriptCreate() { + return Script; + } + } +} diff --git a/model/model.csproj b/model/model.csproj index d9a25b77..fc07ec8a 100644 --- a/model/model.csproj +++ b/model/model.csproj @@ -41,6 +41,7 @@ 3.5 + 3.5 @@ -67,6 +68,7 @@ + diff --git a/test/DatabaseTester.cs b/test/DatabaseTester.cs index 58f9b6e4..6a43e69b 100644 --- a/test/DatabaseTester.cs +++ b/test/DatabaseTester.cs @@ -106,6 +106,43 @@ public void TestCopy() { } } + [Test] + public void TestTableIndexesWithFilter() { + TestHelper.DropDb("TEST"); + TestHelper.ExecSql("CREATE DATABASE TEST",""); + + TestHelper.ExecSql(@"CREATE TABLE MyTable (Id int, EndDate datetime)", "TEST"); + TestHelper.ExecSql(@"CREATE NONCLUSTERED INDEX MyIndex ON MyTable (Id) WHERE (EndDate) IS NULL","TEST"); + + var db = new Database("TEST") { + Connection = TestHelper.GetConnString("TEST") + }; + db.Load(); + var result = db.ScriptCreate(); + TestHelper.DropDb("TEST"); + + Assert.That(result, Is.StringContaining("CREATE NONCLUSTERED INDEX [MyIndex] ON [dbo].[MyTable] ([Id]) WHERE ([EndDate] IS NULL)")); + } + + [Test] + public void TestViewIndexes() { + TestHelper.DropDb("TEST"); + TestHelper.ExecSql("CREATE DATABASE TEST", ""); + + TestHelper.ExecSql(@"CREATE TABLE MyTable (Id int, Name nvarchar(250), EndDate datetime)", "TEST"); + TestHelper.ExecSql(@"CREATE VIEW dbo.MyView WITH SCHEMABINDING as SELECT t.Id, t.Name, t.EndDate from dbo.MyTable t", "TEST"); + TestHelper.ExecSql(@"CREATE UNIQUE CLUSTERED INDEX MyIndex ON MyView (Id, Name)", "TEST"); + + var db = new Database("TEST") { + Connection = TestHelper.GetConnString("TEST") + }; + db.Load(); + var result = db.ScriptCreate(); + TestHelper.DropDb("TEST"); + + Assert.That(result, Is.StringContaining("CREATE UNIQUE CLUSTERED INDEX [MyIndex] ON [dbo].[MyView] ([Id], [Name])")); + } + [Test] [Ignore("test won't work without license key for sqldbdiff")] public void TestDiffScript() { @@ -242,7 +279,7 @@ CREATE TYPE [dbo].[MyTableType] AS TABLE( [Value] [varchar](50) NOT NULL, PRIMARY KEY CLUSTERED ( - [ID] ASC + [ID] ) ) @@ -413,13 +450,16 @@ public void TestScriptToDir() { formType.Columns.Add(new Column("code", "tinyint", false, null) {Position = 1}); formType.Columns.Add(new Column("desc", "varchar", 10, false, null) {Position = 2}); formType.AddConstraint(new Constraint("PK_FormType", "PRIMARY KEY", "code") { Clustered = true, Unique = true }); - formType.AddConstraint(Constraint.CreateCheckedConstraint("CK_FormType", false, "([code]<(5))")); - + formType.AddConstraint(Constraint.CreateCheckedConstraint("CK_FormType", false, "([code]<(5))")); - var categoryType = new Table("dbo", "CategoryType"); - categoryType.Columns.Add(new Column("id", "int", false, null) { Position = 1 }); - categoryType.Columns.Add(new Column("Category", "varchar", 10, false, null) { Position = 2 }); - categoryType.AddConstraint(new Constraint("PK_CategoryType", "PRIMARY KEY", "id") { Clustered = true, Unique = true }); + var categoryType = new Table("dbo", "CategoryType"); + categoryType.Columns.Add(new Column("id", "int", false, null) { Position = 1 }); + categoryType.Columns.Add(new Column("Category", "varchar", 10, false, null) { Position = 2 }); + categoryType.AddConstraint(new Constraint("PK_CategoryType", "PRIMARY KEY", "id") { Clustered = true, Unique = true }); + + var emptyTable = new Table("dbo", "EmptyTable"); + emptyTable.Columns.Add(new Column("code", "tinyint", false, null) {Position = 1}); + emptyTable.AddConstraint(new Constraint("PK_EmptyTable", "PRIMARY KEY", "code") {Clustered = true, Unique = true}); var fk_policy_formType = new ForeignKey("FK_Policy_FormType"); fk_policy_formType.Table = policy; @@ -454,12 +494,13 @@ public void TestScriptToDir() { var db = new Database("ScriptToDirTest"); db.Tables.Add(policy); db.Tables.Add(formType); - db.Tables.Add(categoryType); + db.Tables.Add(categoryType); + db.Tables.Add(emptyTable); db.Tables.Add(loc); db.TableTypes.Add(tt_codedesc); db.ForeignKeys.Add(fk_policy_formType); db.ForeignKeys.Add(fk_location_policy); - db.ForeignKeys.Add(fk_location_category); + db.ForeignKeys.Add(fk_location_category); db.FindProp("COMPATIBILITY_LEVEL").Value = "110"; db.FindProp("COLLATE").Value = "SQL_Latin1_General_CP1_CI_AS"; db.FindProp("AUTO_CLOSE").Value = "OFF"; @@ -496,6 +537,7 @@ public void TestScriptToDir() { + "insert into formType ([code], [desc]) values (3, 'DP-3')"); db.DataTables.Add(formType); + db.DataTables.Add(emptyTable); db.Dir = db.Name; if (Directory.Exists(db.Dir)) @@ -508,7 +550,11 @@ public void TestScriptToDir() { Assert.IsTrue(Directory.Exists(db.Name + "\\foreign_keys")); foreach (var t in db.DataTables) { - Assert.IsTrue(File.Exists(db.Name + "\\data\\" + t.Name + ".tsv")); + if (t.Name == "EmptyTable") { + Assert.IsFalse(File.Exists(db.Name + "\\data\\" + t.Name + ".tsv")); + } else { + Assert.IsTrue(File.Exists(db.Name + "\\data\\" + t.Name + ".tsv")); + } } foreach (var t in db.Tables) { var tblFile = db.Name + "\\tables\\" + t.Name + ".sql";