Skip to content

Commit

Permalink
Merge branch 'Zocdoc-master'
Browse files Browse the repository at this point in the history
  • Loading branch information
sethreno committed Apr 22, 2016
2 parents 5a5b465 + 3550716 commit 16f1e3e
Show file tree
Hide file tree
Showing 4 changed files with 242 additions and 31 deletions.
188 changes: 167 additions & 21 deletions model/Database.cs
Original file line number Diff line number Diff line change
Expand Up @@ -70,7 +70,8 @@ public Database(string name)
public List<Synonym> Synonyms = new List<Synonym>();
public List<Table> TableTypes = new List<Table>();
public List<Table> Tables = new List<Table>();
public List<SqlUser> Users = new List<SqlUser>();
public List<Role> Roles = new List<Role>();
public List<SqlUser> Users = new List<SqlUser>();
public List<Constraint> ViewIndexes = new List<Constraint>();

public DbProp FindProp(string name) {
Expand Down Expand Up @@ -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) {
Expand All @@ -121,7 +122,7 @@ public List<Table> 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) {
Expand All @@ -148,6 +149,7 @@ public void Load() {
Assemblies.Clear();
Users.Clear();
Synonyms.Clear();
Roles.Clear();

using (var cn = new SqlConnection(Connection)) {
cn.Open();
Expand All @@ -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 = @"
Expand All @@ -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
Expand Down Expand Up @@ -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
Expand Down Expand Up @@ -1043,7 +1179,8 @@ public void ScriptToDir(string tableHint = null, Action<TraceLevel, string> 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);
Expand Down Expand Up @@ -1124,10 +1261,19 @@ public void ExportData(string tableHint = null, Action<TraceLevel, string> 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();
}
}
}

Expand Down
17 changes: 17 additions & 0 deletions model/Role.cs
Original file line number Diff line number Diff line change
@@ -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;
}
}
}
2 changes: 2 additions & 0 deletions model/model.csproj
Original file line number Diff line number Diff line change
Expand Up @@ -41,6 +41,7 @@
<Reference Include="System.Core">
<RequiredTargetFramework>3.5</RequiredTargetFramework>
</Reference>
<Reference Include="System.Web" />
<Reference Include="System.Xml.Linq">
<RequiredTargetFramework>3.5</RequiredTargetFramework>
</Reference>
Expand All @@ -67,6 +68,7 @@
<Compile Include="Identity.cs" />
<Compile Include="Interfaces.cs" />
<Compile Include="Properties\AssemblyInfo.cs" />
<Compile Include="Role.cs" />
<Compile Include="Routine.cs" />
<Compile Include="SqlUser.cs" />
<Compile Include="Synonym.cs" />
Expand Down
Loading

0 comments on commit 16f1e3e

Please sign in to comment.