SQL Server 2019 Data Classification

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 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 |
--Ref --https://github.com/microsoft/sqlworkshops-sql2019lab/tree/master/sql2019lab/02_Security/dataclassification --★★★Demo1★★★ --既存の分類を削除する前にこれらのデモを実行した場合 USE [WideWorldImporters] GO IF EXISTS (SELECT * FROM sys.sensitivity_classifications sc WHERE object_id('[Application].[PaymentMethods]') = sc.major_id) BEGIN DROP SENSITIVITY CLASSIFICATION FROM [Application].[PaymentMethods].[PaymentMethodName] END GO IF EXISTS (SELECT * FROM sys.sensitivity_classifications sc WHERE object_id('[Application].[People]') = sc.major_id) BEGIN DROP SENSITIVITY CLASSIFICATION FROM [Application].[People].[FullName] DROP SENSITIVITY CLASSIFICATION FROM [Application].[People].[EmailAddress] END GO --分類の確認(for SQL Server 2019) USE [WideWorldImporters] GO SELECT SCHEMA_NAME(sys.all_objects.schema_id) as SchemaName, sys.all_objects.[name] AS [TableName], sys.all_columns.[name] As [ColumnName], [Label], [Label_ID], [Information_Type], [Information_Type_ID], [Rank], [Rank_Desc] FROM sys.sensitivity_classifications left join sys.all_objects on sys.sensitivity_classifications.major_id = sys.all_objects.object_id left join sys.all_columns on sys.sensitivity_classifications.major_id = sys.all_columns.object_id and sys.sensitivity_classifications.minor_id = sys.all_columns.column_id --★★★Demo2★★★ --独自分類の追加1(SQL Server 2019) --PII = Personally Identifiable Information ADD SENSITIVITY CLASSIFICATION TO [Application].[People].[EmailAddress] WITH (LABEL='PII', INFORMATION_TYPE='Email') GO --感度の分類の確認(for SQL Server 2019) SELECT SCHEMA_NAME(sys.all_objects.schema_id) as SchemaName, sys.all_objects.[name] AS [TableName], sys.all_columns.[name] As [ColumnName], [Label], [Label_ID], [Information_Type], [Information_Type_ID], [Rank], [Rank_Desc] FROM sys.sensitivity_classifications left join sys.all_objects on sys.sensitivity_classifications.major_id = sys.all_objects.object_id left join sys.all_columns on sys.sensitivity_classifications.major_id = sys.all_columns.object_id and sys.sensitivity_classifications.minor_id = sys.all_columns.column_id --Label_IDにはまだ値を指定していませんが、問題ありません。 --これにより、人間が読めるメタデータを列に追加したり、外部監査システムから取得したIDを追加したりできます。 --https://docs.microsoft.com/ja-jp/sql/t-sql/statements/drop-sensitivity-classification-transact-sql?view=azuresqldb-current&viewFallbackFrom=sql-server-ver15 DROP SENSITIVITY CLASSIFICATION FROM [Application].[People].[EmailAddress] GO --独自分類の追加2(SQL Server 2019) --LABEL --人間が判読できる機密ラベルの名前です。 機密ラベルは、データベース列に格納されているデータの秘密度を表します。 --LABEL_ID --機密ラベルに関連付けられている識別子です。 多くの場合、システムにおいてラベルを一意に識別するために、一元的な情報保護プラットフォームで使用されます。Azure Information Protection (AIP) などの情報保護システムで使用できます。 --INFORMATION_TYPE --人間が判読できる情報の種類の名前です。 情報の種類は、データベース列に格納されているデータの種類を記述するために使用されます。 --INFORMATION_TYPE_ID --情報の種類に関連付けられている識別子です。 多くの場合、システムにおいて情報の種類を一意に識別するために、一元的な情報保護プラットフォームで使用されます。Azure Information Protection (AIP) などの情報保護システムで使用できます。 --RANK --感度の順位を定義する事前定義された値セットに基づく識別子です。 Advanced Threat Protection などの他のサービスによって使用され、順位に基づいて異常を検出します。 --RANK = NONE | LOW | MEDIUM | HIGH | CRITICAL --仕様上では、NEWID()を直接埋め込んで実行することはできない ADD SENSITIVITY CLASSIFICATION TO [Application].[People].[EmailAddress] WITH (LABEL='PII', LABEL_ID=NEWID(), INFORMATION_TYPE='Email', INFORMATION_TYPE_ID=NEWID(), RANK=MEDIUM ) GO SELECT NEWID() --https://docs.microsoft.com/ja-jp/sql/t-sql/statements/add-sensitivity-classification-transact-sql?view=sql-server-ver15 --SSMS 18.5 Added support for sensitivity rank in Data Classification. ADD SENSITIVITY CLASSIFICATION TO [Application].[People].[EmailAddress] --PIIとはPersonally Identifiable Information、個人を特定できる情報 WITH (LABEL='PII', LABEL_ID='B0B3C403-14A5-405D-9E01-03F4F1674817', --LABEL_ID=NEWID(), INFORMATION_TYPE='Email', INFORMATION_TYPE_ID='A7460053-D35A-47CF-832A-2BF12EBE5006', --INFORMATION_TYPE_ID=NEWID(), RANK=MEDIUM ) GO SELECT SCHEMA_NAME(sys.all_objects.schema_id) as SchemaName, sys.all_objects.[name] AS [TableName], sys.all_columns.[name] As [ColumnName], [Label], [Label_ID], [Information_Type], [Information_Type_ID], [Rank], [Rank_Desc] FROM sys.sensitivity_classifications left join sys.all_objects on sys.sensitivity_classifications.major_id = sys.all_objects.object_id left join sys.all_columns on sys.sensitivity_classifications.major_id = sys.all_columns.object_id and sys.sensitivity_classifications.minor_id = sys.all_columns.column_id --★★★Demo3★★★ --Using SQL Server Audit with Data Classification -- Step 1: Disable the audits and drop them USE WideWorldImporters GO IF EXISTS (SELECT * FROM sys.database_audit_specifications WHERE name = 'People_Audit') BEGIN ALTER DATABASE AUDIT SPECIFICATION People_Audit WITH (STATE = OFF) DROP DATABASE AUDIT SPECIFICATION People_Audit END GO USE master GO IF EXISTS (SELECT * FROM sys.server_audits WHERE name = 'Classification_Audit') BEGIN ALTER SERVER AUDIT Classification_Audit WITH (STATE = OFF) DROP SERVER AUDIT Classification_Audit END GO --サーバー監査の定義 -- Note: Remember for Linux installations, the default path is /var/opt/mssql/data USE [master] GO CREATE SERVER AUDIT [Classification_Audit] TO FILE ( FILEPATH = N'C:\SQLServerAuditLog\20200425' ,MAXSIZE = 0 MB ,MAX_ROLLOVER_FILES = 2147483647 ,RESERVE_DISK_SPACE = OFF ) WITH ( QUEUE_DELAY = 1000 ,ON_FAILURE = CONTINUE ) GO --サーバー監査を有効にする ALTER SERVER AUDIT [Classification_Audit] WITH (STATE = ON) GO --データベース監査の定義 USE [WideWorldImporters] GO CREATE DATABASE AUDIT SPECIFICATION [People_Audit] FOR SERVER AUDIT [Classification_Audit] ADD (SELECT ON OBJECT::[Application].[People] BY [public]) WITH (STATE = ON) GO --アクセスする、足跡を残るようにする USE [WideWorldImporters] GO SELECT * FROM [Application].[People] GO -- Check the audit -- The audit may now show up EXACTLY right after the query but within a few seconds. -- Note: Remember for Linux installations, the default path is /var/opt/mssql/data SELECT event_time, session_id, server_principal_name, database_name, object_name, cast(data_sensitivity_information as XML) as data_sensitivity_information, client_ip, application_name FROM sys.fn_get_audit_file ('C:\SQLServerAuditLog\20200425\*.sqlaudit',default,default) GO SELECT event_time,action_id as [Activity], statement as [Query], [object] = [database_name] + '.' + [schema_name] + '.' + [object_name], data_sensitivity_information = CONVERT(xml, data_sensitivity_information) FROM sys.fn_get_audit_file('C:\SQLServerAuditLog\20200425\*.sqlaudit',default,default) WHERE action_id = 'SL' GO --ちなみに、action_idの確認方法 SELECT DISTINCT action_id,name FROM sys.dm_audit_actions SELECT DISTINCT action_id,name,class_desc,parent_class_desc FROM sys.dm_audit_actions where action_id = 'SL' --アクセスする、Classification対象外のものをアクセスする SELECT FullName FROM [Application].[People] GO SELECT event_time, session_id, server_principal_name, database_name, object_name, cast(data_sensitivity_information as XML) as data_sensitivity_information, client_ip, application_name FROM sys.fn_get_audit_file ('C:\SQLServerAuditLog\20200425\*.sqlaudit',default,default) GO SELECT event_time,action_id as [Activity], statement as [Query], [object] = [database_name] + '.' + [schema_name] + '.' + [object_name], data_sensitivity_information = CONVERT(xml, data_sensitivity_information) FROM sys.fn_get_audit_file('C:\SQLServerAuditLog\20200425\*.sqlaudit',default,default) WHERE action_id = 'SL' GO --条件指定してアクセスする、監査対象になるが、存在していないレコードを検索する SELECT PreferredName FROM [Application].[People] WHERE EmailAddress LIKE '%microsoft%' GO SELECT event_time, session_id, server_principal_name, database_name, object_name, cast(data_sensitivity_information as XML) as data_sensitivity_information, client_ip, application_name FROM sys.fn_get_audit_file ('C:\SQLServerAuditLog\20200425\*.sqlaudit',default,default) GO SELECT event_time,action_id as [Activity], statement as [Query], [object] = [database_name] + '.' + [schema_name] + '.' + [object_name], data_sensitivity_information = CONVERT(xml, data_sensitivity_information) FROM sys.fn_get_audit_file('C:\SQLServerAuditLog\20200425\*.sqlaudit',default,default) WHERE action_id = 'SL' GO --Demoクリア USE WideWorldImporters GO IF EXISTS (SELECT * FROM sys.database_audit_specifications WHERE name = 'People_Audit') BEGIN ALTER DATABASE AUDIT SPECIFICATION People_Audit WITH (STATE = OFF) DROP DATABASE AUDIT SPECIFICATION People_Audit END GO USE master GO IF EXISTS (SELECT * FROM sys.server_audits WHERE name = 'Classification_Audit') BEGIN ALTER SERVER AUDIT Classification_Audit WITH (STATE = OFF) DROP SERVER AUDIT Classification_Audit END GO --★★★Demo4★★★ --日本語のカラム名の検出と分類 USE [NorthwindJ] GO SELECT NEWID() ADD SENSITIVITY CLASSIFICATION TO [dbo].[社員].[氏名] --PIIとはPersonally Identifiable Information、個人を特定できる情報 WITH (LABEL='個人情報', LABEL_ID='CA9E00D6-815F-4857-990A-B2DD50620753', --LABEL_ID=NEWID(), INFORMATION_TYPE='名前情報', INFORMATION_TYPE_ID='6955C739-332D-4841-96E6-A149EFF511DB', --INFORMATION_TYPE_ID=NEWID(), RANK=MEDIUM ) GO IF EXISTS (SELECT * FROM sys.database_audit_specifications WHERE name = 'People_Audit') BEGIN ALTER DATABASE AUDIT SPECIFICATION People_Audit WITH (STATE = OFF) DROP DATABASE AUDIT SPECIFICATION People_Audit END GO USE master GO IF EXISTS (SELECT * FROM sys.server_audits WHERE name = 'Classification_Audit') BEGIN ALTER SERVER AUDIT Classification_Audit WITH (STATE = OFF) DROP SERVER AUDIT Classification_Audit END GO --サーバー監査を定義する USE [master] GO CREATE SERVER AUDIT [Classification_Audit] TO FILE ( FILEPATH = N'C:\SQLServerAuditLog\20200425' ,MAXSIZE = 0 MB ,MAX_ROLLOVER_FILES = 2147483647 ,RESERVE_DISK_SPACE = OFF ) WITH ( QUEUE_DELAY = 1000 ,ON_FAILURE = CONTINUE ) GO --サーバー監査を有効にする --データベース監査の定義 USE [NorthwindJ] GO CREATE DATABASE AUDIT SPECIFICATION [People_Audit] FOR SERVER AUDIT [Classification_Audit] ADD (SELECT ON OBJECT::[dbo].[社員] BY [public]) WITH (STATE = ON) GO --アクセスする、足跡を残るようにする USE [NorthwindJ] GO SELECT * FROM [dbo].[社員] GO SELECT event_time,action_id as [Activity], statement as [Query], [object] = [database_name] + '.' + [schema_name] + '.' + [object_name], data_sensitivity_information = CONVERT(xml, data_sensitivity_information) FROM sys.fn_get_audit_file('C:\SQLServerAuditLog\20200425\*.sqlaudit',default,default) WHERE action_id = 'SL' GO --Cleaning USE [NorthwindJ] GO IF EXISTS (SELECT * FROM sys.database_audit_specifications WHERE name = 'People_Audit') BEGIN ALTER DATABASE AUDIT SPECIFICATION People_Audit WITH (STATE = OFF) DROP DATABASE AUDIT SPECIFICATION People_Audit END GO USE master GO IF EXISTS (SELECT * FROM sys.server_audits WHERE name = 'Classification_Audit') BEGIN ALTER SERVER AUDIT Classification_Audit WITH (STATE = OFF) DROP SERVER AUDIT Classification_Audit END GO --SQL Server 2019以前のテーブル拡張プロパティからの移行方法について DECLARE @sql nvarchar(max) = N'' SELECT @sql += N'ADD SENSITIVITY CLASSIFICATION TO ' + QUOTENAME(s.name) + QUOTENAME(o.name) + QUOTENAME(c.name) + ' WITH (LABEL = ''' + REPLACE(CONVERT(nvarchar(256), l.[value]), '''', '''''') + ''', INFORMATION_TYPE = ''' + REPLACE(CONVERT(nvarchar(256), t.[value]), '''', '''''') + ''');' + CHAR(13) + CHAR(10) FROM sys.extended_properties AS t INNER JOIN sys.extended_properties AS l ON t.class = l.class AND t.major_id = l.major_id AND t.minor_id = l.minor_id INNER JOIN sys.objects AS o ON t.major_id = o.[object_id] INNER JOIN sys.columns AS c ON t.major_id = c.[object_id] AND t.minor_id = c.column_id INNER JOIN sys.schemas AS s ON o.[schema_id] = s.[schema_id] WHERE t.name = N'sys_information_type_name' AND l.name = N'sys_sensitivity_label_name' PRINT @sql GO |