-
Notifications
You must be signed in to change notification settings - Fork 8
/
Copy pathRepositorySchemaObjects.sql
164 lines (133 loc) · 4.94 KB
/
RepositorySchemaObjects.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
CREATE SCHEMA [Permissions]
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [Permissions].[Captures](
[ID] [int] IDENTITY(1,1) NOT NULL,
[CaptureID] [uniqueidentifier] NOT NULL,
[CaptureDateTime] [datetime2](7) NOT NULL,
[ServerName] [nvarchar](50) NOT NULL,
[InstanceName] [nvarchar](50) NOT NULL,
[DatabaseName] [nvarchar](150) NOT NULL,
PRIMARY KEY CLUSTERED
(
[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 80) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [Permissions].[DatabaseObjectPermissions] Script Date: 2/2/2018 3:26:05 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [Permissions].[DatabaseObjectPermissions](
[ID] [int] IDENTITY(1,1) NOT NULL,
[CaptureID] [uniqueidentifier] NOT NULL,
[ObjectClass] [nvarchar](150) NULL,
[ObjectSchema] [nvarchar](150) NULL,
[ObjectName] [nvarchar](150) NOT NULL,
[PermissionState] [nvarchar](50) NOT NULL,
[PermissionType] [nvarchar](50) NOT NULL,
[Grantee] [nvarchar](150) NOT NULL,
[CreateScript] [nvarchar](max) NULL,
PRIMARY KEY CLUSTERED
(
[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 80) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
GO
/****** Object: Table [Permissions].[DatabaseRoleMembers] Script Date: 2/2/2018 3:26:05 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [Permissions].[DatabaseRoleMembers](
[ID] [int] IDENTITY(1,1) NOT NULL,
[CaptureID] [uniqueidentifier] NOT NULL,
[RoleName] [nvarchar](100) NOT NULL,
[RoleMember] [nvarchar](100) NOT NULL,
[CreateScript] [nvarchar](max) NULL,
PRIMARY KEY CLUSTERED
(
[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 80) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
GO
/****** Object: Table [Permissions].[DatabaseUsers] Script Date: 2/2/2018 3:26:05 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [Permissions].[DatabaseUsers](
[ID] [int] IDENTITY(1,1) NOT NULL,
[CaptureID] [uniqueidentifier] NOT NULL,
[UserName] [nvarchar](100) NOT NULL,
[CreateScript] [nvarchar](max) NULL,
PRIMARY KEY CLUSTERED
(
[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 80) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
GO
CREATE PROCEDURE [Permissions].[GetPermissions]
@ForServer nvarchar(255),
@ForDatabase nvarchar(255),
@ForDate date
AS
BEGIN
SET NOCOUNT ON;
DECLARE @WorkingDate DATE
SELECT TOP (1000) [ID]
,[CaptureID]
,[CaptureDateTime]
,[ServerName]
,[InstanceName]
,[DatabaseName]
INTO #AllCaptures
FROM [Admin].[Permissions].[Captures]
where servername = @ForServer
order by capturedatetime desc
IF @ForDate IS NULL
BEGIN
select top 1 @ForDate = CaptureDateTime from #AllCaptures where servername = 'int-excelsql-02\con3'
group by capturedatetime
order by CaptureDateTime DESC
END
DELETE FROM #AllCaptures WHERE CAST(CaptureDateTime AS DATE) <> @ForDate
IF @ForDatabase IS NULL
BEGIN
DELETE FROM #AllCaptures WHERE DatabaseName <> @ForDatabase
END
SELECT c.CaptureDateTime, c.ServerName, c.InstanceName, c.DatabaseName, 'USE [' + c.DatabaseName + ']; ' + CreateScript
FROM Permissions.DatabaseUsers u
INNER JOIN Permissions.Captures c ON c.CaptureID = u.CaptureID
INNER JOIN #AllCaptures ac ON ac.CaptureID = c.CaptureID
UNION ALL
SELECT
c.CaptureDateTime, c.ServerName, c.InstanceName, c.DatabaseName, 'USE [' + c.DatabaseName + ']; ' + 'ALTER ROLE ' + r.RoleName + ' ADD MEMBER [' + r.RoleMember + ']'
FROM Permissions.DatabaseRoleMembers r
INNER JOIN Permissions.Captures c ON c.CaptureID = r.CaptureID
INNER JOIN #AllCaptures ac ON ac.CaptureID = c.CaptureID
UNION ALL
SELECT
c.CaptureDateTime, c.ServerName, c.InstanceName, c.DatabaseName, 'USE [' + c.DatabaseName + ']; ' + (p.PermissionState + ' ' + p.PermissionType + ' TO [' + p.Grantee + ']')
FROM Permissions.DatabaseObjectPermissions p
INNER JOIN Permissions.Captures c ON c.CaptureID = p.CaptureID
INNER JOIN #AllCaptures ac ON ac.CaptureID = c.CaptureID
AND ObjectClass = 'Database'
UNION ALL
SELECT
c.CaptureDateTime, c.ServerName, c.InstanceName, c.DatabaseName,
Code =
CASE
WHEN ObjectClass = 'Schema' THEN 'USE [' + c.DatabaseName + ']; ' + ' ' + permissionState + ' ' + permissionType + ' ON SCHEMA:: [' + ObjectName + '] TO [' + Grantee + ']'
ELSE 'USE [' + c.DatabaseName + ']; ' + permissionState + ' ' + permissionType + ' ON [' + objectSchema + '].[' + objectname + '] TO [' + grantee + ']'
END
FROM Permissions.DatabaseObjectPermissions p
INNER JOIN Permissions.Captures c ON c.CaptureID = p.CaptureID
INNER JOIN #AllCaptures ac ON ac.CaptureID = c.CaptureID
AND ObjectClass != 'Database'
END
GO