Encryption of Data in SQL Server 2019

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 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 |
/*************** 対称キーによる列レベルの暗号化 ***************/ USE [JSSUG_DEV] GO DROP TABLE Employees GO -- Create sample table CREATE TABLE Employees ( EmployeeID INT PRIMARY KEY, EmployeeName VARCHAR(300), Position VARCHAR(100), Salary VARBINARY(max) ) GO -- Create SMK CREATE SYMMETRIC KEY SMK_Emp WITH ALGORITHM = AES_256 ENCRYPTION BY PASSWORD = 'Pa$$w0rd' GO -- Open SMK OPEN SYMMETRIC KEY SMK_Emp DECRYPTION BY PASSWORD = 'Pa$$w0rd' GO -- Verify open keys SELECT * FROM sys.openkeys GO -- Insert data --バイナリ値をコピー、後で比較用 INSERT Employees VALUES (1, 'Aさん', 'CTO', ENCRYPTBYKEY(KEY_GUID('SMK_Emp'),'$100000')) INSERT Employees VALUES (2, 'Bさん', 'CIO', ENCRYPTBYKEY(KEY_GUID('SMK_Emp'),'$200000')) INSERT Employees VALUES (3, 'Cさん', 'CEO', ENCRYPTBYKEY(KEY_GUID('SMK_Emp'),'$300000')) GO -- Query table with encrypted values SELECT * FROM Employees GO -- Query table with decrypted values SELECT *, CONVERT(VARCHAR, DECRYPTBYKEY(Salary)) AS DecryptedSalary FROM Employees GO -- Close SMK CLOSE SYMMETRIC KEY SMK_Emp GO -- Query table with decrypted values after key SMK is closed SELECT *, CONVERT(VARCHAR, DECRYPTBYKEY(Salary)) AS DecryptedSalary FROM Employees GO -- Clever CTO updates their salary to match CEO's salary UPDATE Employees SET Salary = (SELECT Salary FROM Employees WHERE Position = 'CEO') WHERE EmployeeName = 'Aさん' GO -- Open SMK and query table with decrypted values OPEN SYMMETRIC KEY SMK_Emp DECRYPTION BY PASSWORD = 'Pa$$w0rd' GO SELECT *, CONVERT(VARCHAR, DECRYPTBYKEY(Salary)) AS DecryptedSalary FROM Employees GO -- Cleanup DROP TABLE Employees DROP SYMMETRIC KEY SMK_Emp GO /*************** 非対称キーによる列レベルの暗号化 ***************/ USE [JSSUG_DEV] GO -- Create sample table CREATE TABLE Employees ( EmployeeID INT PRIMARY KEY, EmployeeName VARCHAR(300), Position VARCHAR(100), Salary VARBINARY(max) ) GO --インスタンスレベルServiceMasterKey(ServiceMasterkey)、確認してから実行してください。省略可能 USE [master] GO IF NOT EXISTS( SELECT * FROM sys.symmetric_keys WHERE name = '##MS_ServiceMasterKey##') BEGIN CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'Pa$$w0rd' END GO --データベースレベルMasterKey USE [JSSUG_DEV] GO IF NOT EXISTS (SELECT * FROM sys.symmetric_keys WHERE name LIKE '%MS_DatabaseMasterKey%') BEGIN CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'Pa$$w0rd' END GO -- Create ASMK USE [JSSUG_DEV] GO IF NOT EXISTS (SELECT * FROM sys.asymmetric_keys WHERE name = 'ASMK_Emp') BEGIN CREATE ASYMMETRIC KEY ASMK_Emp /* <algorithm> ::= { RSA_4096 | RSA_3072 | RSA_2048 | RSA_1024 | RSA_512 } */ WITH ALGORITHM = RSA_4096 ENCRYPTION BY PASSWORD = 'Pa$$w0rd' END GO -- Insert data INSERT Employees VALUES (1, 'Aさん', 'CTO', ENCRYPTBYASYMKEY(ASYMKEY_ID('ASMK_Emp'),'$100000')) INSERT Employees VALUES (2, 'Bさん', 'CIO', ENCRYPTBYASYMKEY(ASYMKEY_ID('ASMK_Emp'),'$200000')) INSERT Employees VALUES (3, 'Cさん', 'CEO', ENCRYPTBYASYMKEY(ASYMKEY_ID('ASMK_Emp'),'$300000')) GO -- Query table with encrypted values SELECT * FROM Employees GO -- Query table with decrypted values SELECT *, CONVERT(VARCHAR, DECRYPTBYASYMKEY(ASYMKEY_ID('ASMK_Emp'),Salary,N'Pa$$w0rd')) AS DecryptedSalary FROM Employees GO -- Clever CTO updates their salary to match CEO's salary UPDATE Employees SET Salary = (SELECT Salary FROM Employees WHERE Position = 'CEO') WHERE EmployeeName = 'Aさん' GO -- 確認 SELECT *, CONVERT(VARCHAR, DECRYPTBYASYMKEY(ASYMKEY_ID('ASMK_Emp'),Salary,N'Pa$$w0rd')) AS DecryptedSalary FROM Employees GO -- Cleanup DROP TABLE Employees DROP ASYMMETRIC KEY ASMK_Emp DROP MASTER KEY GO /*************** 対称キー+非対称キーによる列レベルの暗号化 非対称キーで対称キーを暗号化パターン ***************/ USE [JSSUG_DEV] GO -- Create sample table CREATE TABLE Employees ( EmployeeID INT PRIMARY KEY, EmployeeName VARCHAR(300), Position VARCHAR(100), Salary VARBINARY(max) ) GO --インスタンスレベルServiceMasterKey(ServiceMasterkey)、確認してから実行してください。省略可能 USE [master] GO IF NOT EXISTS( SELECT * FROM sys.symmetric_keys WHERE name = '##MS_ServiceMasterKey##') BEGIN CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'Pa$$w0rd' END GO --データベースレベルMasterKey USE [JSSUG_DEV] GO IF NOT EXISTS (SELECT * FROM sys.symmetric_keys WHERE name LIKE '%MS_DatabaseMasterKey%') BEGIN CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'Pa$$w0rd' END GO -- Create ASMK USE [JSSUG_DEV] GO IF NOT EXISTS (SELECT * FROM sys.asymmetric_keys WHERE name = 'ASMK_Emp') BEGIN CREATE ASYMMETRIC KEY ASMK_Emp /* <algorithm> ::= { RSA_4096 | RSA_3072 | RSA_2048 | RSA_1024 | RSA_512 } */ WITH ALGORITHM = RSA_4096 ENCRYPTION BY PASSWORD = 'Pa$$w0rd' END GO -- Create SMK CREATE SYMMETRIC KEY SMK_Emp WITH ALGORITHM = AES_256 ENCRYPTION BY ASYMMETRIC KEY ASMK_Emp GO -- Open SMK OPEN SYMMETRIC KEY SMK_Emp DECRYPTION BY ASYMMETRIC KEY ASMK_Emp WITH PASSWORD = 'Pa$$w0rd' GO -- Verify open keys SELECT * FROM sys.openkeys GO -- Insert data INSERT Employees VALUES (1, 'Aさん', 'CTO', ENCRYPTBYKEY(KEY_GUID('SMK_Emp'),'$100000')) INSERT Employees VALUES (2, 'Bさん', 'CIO', ENCRYPTBYKEY(KEY_GUID('SMK_Emp'),'$200000')) INSERT Employees VALUES (3, 'Cさん', 'CEO', ENCRYPTBYKEY(KEY_GUID('SMK_Emp'),'$300000')) GO -- Query table with encrypted values SELECT * FROM Employees GO -- Query table with decrypted values SELECT *, CONVERT(VARCHAR, DECRYPTBYKEY(Salary)) AS DecryptedSalary FROM Employees GO -- Close SMK CLOSE SYMMETRIC KEY SMK_Emp GO -- Query table with decrypted values after key SMK is closed SELECT *, CONVERT(VARCHAR, DECRYPTBYKEY(Salary)) AS DecryptedSalary FROM Employees GO -- Clever CTO updates their salary to match CEO's salary UPDATE Employees SET Salary = (SELECT Salary FROM Employees WHERE Position = 'CEO') WHERE EmployeeName = 'Aさん' GO -- Open SMK and query table with decrypted values OPEN SYMMETRIC KEY SMK_Emp DECRYPTION BY ASYMMETRIC KEY ASMK_Emp WITH PASSWORD = 'Pa$$w0rd'; SELECT *, CONVERT(VARCHAR, DECRYPTBYKEY(Salary)) AS DecryptedSalary FROM Employees GO -- Cleanup DROP TABLE Employees DROP SYMMETRIC KEY SMK_Emp DROP ASYMMETRIC KEY ASMK_Emp DROP MASTER KEY GO /*************** 証明書による列レベルの暗号化 ***************/ USE [JSSUG_DEV] GO -- Create sample table CREATE TABLE Employees ( EmployeeID INT PRIMARY KEY, EmployeeName VARCHAR(300), Position VARCHAR(100), Salary VARBINARY(max) ) GO --インスタンスレベルServiceMasterKey(ServiceMasterkey)、確認してから実行してください。省略可能 USE [master] GO IF NOT EXISTS( SELECT * FROM sys.symmetric_keys WHERE name = '##MS_ServiceMasterKey##') BEGIN CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'Pa$$w0rd' END GO --データベースレベルMasterKey USE [JSSUG_DEV] GO IF NOT EXISTS (SELECT * FROM sys.symmetric_keys WHERE name LIKE '%MS_DatabaseMasterKey%') BEGIN CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'Pa$$w0rd' END GO /**注意 PFX 証明書ファイルを PVK または DER 形式に変換するのに SQL Server 用の Microsoft PVKConverter を使用します https://support.microsoft.com/ja-jp/help/2914662/how-to-use-pfx-formatted-certificates-in-sql-server Ex) PVKConverter.exe -i "C:\SSLCert\jssug.jp.pfx" -o PVK -d Pa$$w0rd -e Pa$$w0rd SQLServerサービスアカウントを対象フォルダに権限割り当てる必要 **/ -- Create CERTIFICATE USE [JSSUG_DEV] GO IF NOT EXISTS (SELECT * FROM sys.certificates WHERE name = 'CERT_Emp') BEGIN CREATE CERTIFICATE CERT_Emp FROM FILE = 'C:\SSLCert\PVK_4.cer' WITH PRIVATE KEY (FILE = 'C:\SSLCert\PVK_4.pvk', DECRYPTION BY PASSWORD = 'Pa$$w0rd') END GO -- Insert data INSERT Employees VALUES (1, 'Aさん', 'CTO', ENCRYPTBYCERT(CERT_ID('CERT_Emp'),'$100000')) INSERT Employees VALUES (2, 'Bさん', 'CIO', ENCRYPTBYCERT(CERT_ID('CERT_Emp'),'$200000')) INSERT Employees VALUES (3, 'Cさん', 'CEO', ENCRYPTBYCERT(CERT_ID('CERT_Emp'),'$300000')) GO -- Query table with encrypted values SELECT * FROM Employees GO -- Query table with decrypted values SELECT *, CONVERT(VARCHAR, DECRYPTBYCERT(CERT_ID('CERT_Emp'),Salary)) AS DecryptedSalary FROM Employees GO -- Clever CTO updates their salary to match CEO's salary UPDATE Employees SET Salary = (SELECT Salary FROM Employees WHERE Position = 'CEO') WHERE EmployeeName = 'Aさん' GO -- 確認 SELECT *, CONVERT(VARCHAR, DECRYPTBYCERT(CERT_ID('CERT_Emp'),Salary)) AS DecryptedSalary FROM Employees GO -- Cleanup DROP TABLE Employees DROP CERTIFICATE CERT_Emp DROP MASTER KEY GO /*************** 証明書+対称キーによる列レベルの暗号化 証明書で対称キーを暗号するパターン ***************/ USE [JSSUG_DEV] GO -- Create sample table CREATE TABLE Employees ( EmployeeID INT PRIMARY KEY, EmployeeName VARCHAR(300), Position VARCHAR(100), Salary VARBINARY(max) ) GO --インスタンスレベルServiceMasterKey(ServiceMasterkey)、確認してから実行してください。省略可能 USE [master] GO IF NOT EXISTS( SELECT * FROM sys.symmetric_keys WHERE name = '##MS_ServiceMasterKey##') BEGIN CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'Pa$$w0rd' END GO --データベースレベルMasterKey USE [JSSUG_DEV] GO IF NOT EXISTS (SELECT * FROM sys.symmetric_keys WHERE name LIKE '%MS_DatabaseMasterKey%') BEGIN CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'Pa$$w0rd' END GO /**注意 PFX 証明書ファイルを PVK または DER 形式に変換するのに SQL Server 用の Microsoft PVKConverter を使用します https://support.microsoft.com/ja-jp/help/2914662/how-to-use-pfx-formatted-certificates-in-sql-server Ex) PVKConverter.exe -i "C:\SSLCert\jssug.jp.pfx" -o PVK -d Pa$$w0rd -e Pa$$w0rd SQLServerサービスアカウントを対象フォルダに権限割り当てる必要 **/ -- Create CERTIFICATE USE [JSSUG_DEV] GO IF NOT EXISTS (SELECT * FROM sys.certificates WHERE name = 'CERT_Emp') BEGIN CREATE CERTIFICATE CERT_Emp FROM FILE = 'C:\SSLCert\PVK_4.cer' WITH PRIVATE KEY (FILE = 'C:\SSLCert\PVK_4.pvk', DECRYPTION BY PASSWORD = 'Pa$$w0rd') END GO -- Create SMK CREATE SYMMETRIC KEY SMK_Emp WITH ALGORITHM = AES_256 ENCRYPTION BY CERTIFICATE CERT_Emp GO -- Open SMK OPEN SYMMETRIC KEY SMK_Emp DECRYPTION BY CERTIFICATE CERT_Emp GO -- Verify open keys SELECT * FROM sys.openkeys GO -- Insert data INSERT Employees VALUES (1, 'Aさん', 'CTO', ENCRYPTBYKEY(KEY_GUID('SMK_Emp'),'$100000')) INSERT Employees VALUES (2, 'Bさん', 'CIO', ENCRYPTBYKEY(KEY_GUID('SMK_Emp'),'$200000')) INSERT Employees VALUES (3, 'Cさん', 'CEO', ENCRYPTBYKEY(KEY_GUID('SMK_Emp'),'$300000')) GO -- Query table with encrypted values SELECT * FROM Employees GO -- Query table with decrypted values SELECT *, CONVERT(VARCHAR, DECRYPTBYKEY(Salary)) AS DecryptedSalary FROM Employees GO -- Close SMK CLOSE SYMMETRIC KEY SMK_Emp GO -- Query table with decrypted values after key SMK is closed SELECT *, CONVERT(VARCHAR, DECRYPTBYKEY(Salary)) AS DecryptedSalary FROM Employees GO -- Clever CTO updates their salary to match CEO's salary UPDATE Employees SET Salary = (SELECT Salary FROM Employees WHERE Position = 'CEO') WHERE EmployeeName = 'Aさん' GO -- Open SMK and query table with decrypted values OPEN SYMMETRIC KEY SMK_Emp DECRYPTION BY CERTIFICATE CERT_Emp; SELECT *, CONVERT(VARCHAR, DECRYPTBYKEY(Salary)) AS DecryptedSalary FROM Employees GO -- Cleanup DROP TABLE Employees DROP SYMMETRIC KEY SMK_Emp DROP CERTIFICATE CERT_Emp DROP MASTER KEY GO |
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 |
/*************** Transparent Database Encryption ***************/ USE [JSSUG_DEV] GO -- Create sample table CREATE TABLE Employees ( EmployeeID INT PRIMARY KEY, EmployeeName VARCHAR(300), Position VARCHAR(100), Salary VARBINARY(max) ) GO -- Insert data INSERT Employees VALUES (1, 'Aさん', 'CTO', ENCRYPTBYCERT(CERT_ID('CERT_Emp'),'$100000')) INSERT Employees VALUES (2, 'Bさん', 'CIO', ENCRYPTBYCERT(CERT_ID('CERT_Emp'),'$200000')) INSERT Employees VALUES (3, 'Cさん', 'CEO', ENCRYPTBYCERT(CERT_ID('CERT_Emp'),'$300000')) GO --インスタンスレベルServiceMasterKey(ServiceMasterkey)、確認してから実行してください。 USE [master] GO IF NOT EXISTS( SELECT * FROM sys.symmetric_keys WHERE name = '##MS_ServiceMasterKey##') BEGIN CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'Pa$$w0rd' END GO --インスタンスレベルマスタキーを作成、確認してから実行してください。 USE [master] GO IF NOT EXISTS( SELECT * FROM sys.symmetric_keys WHERE name = '##MS_DatabaseMasterKey##') BEGIN CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'Pa$$w0rd' END GO -- Create CERTIFICATE --ここで、自己証明書を作っても問題ない USE [master] GO IF NOT EXISTS (SELECT * FROM sys.certificates WHERE name = 'CERT_Emp') BEGIN CREATE CERTIFICATE CERT_Emp FROM FILE = 'C:\SSLCert\PVK_4.cer' WITH PRIVATE KEY (FILE = 'C:\SSLCert\PVK_4.pvk', DECRYPTION BY PASSWORD = 'Pa$$w0rd') END GO --完全バックアップ(暗号化有効にするときに、データベース暗号化のスキャンを実行する必要があるため、完全復旧モデルの場合、トランザクションログを切り捨てる必要もあるため、ログバックも必要) USE [JSSUG_DEV] GO BACKUP DATABASE [JSSUG_DEV] TO DISK = N'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\Backup\JSSUG_DEV.bak' WITH NOFORMAT, INIT, NAME = N'JSSUG_DEV-完全 データベース バックアップ', SKIP, NOREWIND, NOUNLOAD, NO_COMPRESSION, STATS = 10, CHECKSUM GO declare @backupSetId as int select @backupSetId = position from msdb..backupset where database_name=N'JSSUG_DEV' and backup_set_id=(select max(backup_set_id) from msdb..backupset where database_name=N'JSSUG_DEV' ) if @backupSetId is null begin raiserror(N'確認に失敗しました。データベース ''JSSUG_DEV'' のバックアップ情報が見つかりません。', 16, 1) end RESTORE VERIFYONLY FROM DISK = N'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\Backup\JSSUG_DEV.bak' WITH FILE = @backupSetId, NOUNLOAD, NOREWIND GO --トランザクションログバックアップ(暗号化有効にするときに、データベース暗号化のスキャンを実行する必要があるため、完全復旧モデルの場合、トランザクションログを切り捨てる必要もあるため、ログバックも必要) USE [JSSUG_DEV] GO BACKUP LOG [JSSUG_DEV] TO DISK = N'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\Backup\JSSUG_DEV.trn' WITH NOFORMAT, INIT, NAME = N'JSSUG_DEV-完全 データベース バックアップ', SKIP, NOREWIND, NOUNLOAD, NO_COMPRESSION, STATS = 10, CHECKSUM GO declare @backupSetId as int select @backupSetId = position from msdb..backupset where database_name=N'JSSUG_DEV' and backup_set_id=(select max(backup_set_id) from msdb..backupset where database_name=N'JSSUG_DEV' ) if @backupSetId is null begin raiserror(N'確認に失敗しました。データベース ''JSSUG_DEV'' のバックアップ情報が見つかりません。', 16, 1) end RESTORE VERIFYONLY FROM DISK = N'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\Backup\JSSUG_DEV.trn' WITH FILE = @backupSetId, NOUNLOAD, NOREWIND GO --User DBのTDEの暗号化キーを作成 USE [JSSUG_DEV] GO CREATE DATABASE ENCRYPTION KEY WITH ALGORITHM = AES_256 ENCRYPTION BY SERVER CERTIFICATE CERT_Emp GO --User DBのTDEを有効にする USE [JSSUG_DEV] GO ALTER DATABASE [JSSUG_DEV] SET ENCRYPTION ON GO --TDE有効化後の完全バックアップ USE [JSSUG_DEV] GO BACKUP DATABASE [JSSUG_DEV] TO DISK = N'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\Backup\JSSUG_DEV1.bak' WITH NOFORMAT, INIT, NAME = N'JSSUG_DEV-完全 データベース バックアップ', SKIP, NOREWIND, NOUNLOAD, NO_COMPRESSION, STATS = 10, CHECKSUM GO declare @backupSetId as int select @backupSetId = position from msdb..backupset where database_name=N'JSSUG_DEV' and backup_set_id=(select max(backup_set_id) from msdb..backupset where database_name=N'JSSUG_DEV' ) if @backupSetId is null begin raiserror(N'確認に失敗しました。データベース ''JSSUG_DEV'' のバックアップ情報が見つかりません。', 16, 1) end RESTORE VERIFYONLY FROM DISK = N'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\Backup\JSSUG_DEV1.bak' WITH FILE = @backupSetId, NOUNLOAD, NOREWIND GO --TDE有効化後のトランザクションログバックアップ USE [JSSUG_DEV] GO BACKUP LOG [JSSUG_DEV] TO DISK = N'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\Backup\JSSUG_DEV1.trn' WITH NOFORMAT, INIT, NAME = N'JSSUG_DEV-完全 データベース バックアップ', SKIP, NOREWIND, NOUNLOAD, NO_COMPRESSION, STATS = 10, CHECKSUM GO declare @backupSetId as int select @backupSetId = position from msdb..backupset where database_name=N'JSSUG_DEV' and backup_set_id=(select max(backup_set_id) from msdb..backupset where database_name=N'JSSUG_DEV' ) if @backupSetId is null begin raiserror(N'確認に失敗しました。データベース ''JSSUG_DEV'' のバックアップ情報が見つかりません。', 16, 1) end RESTORE VERIFYONLY FROM DISK = N'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\Backup\JSSUG_DEV1.trn' WITH FILE = @backupSetId, NOUNLOAD, NOREWIND GO /*************** Transparent Database Encryption Backup Certificate and Key ***************/ USE [master] GO -- Backup SMK BACKUP SERVICE MASTER KEY TO FILE = 'C:\SSLCert\ServerMasterKey.key' ENCRYPTION BY PASSWORD = 'Pa$$w0rd' GO -- Backup DMK BACKUP MASTER KEY TO FILE = 'C:\SSLCert\DatabaseMasterKey.key' ENCRYPTION BY PASSWORD = 'Pa$$w0rd' GO -- Backup TDE Certificate BACKUP CERTIFICATE CERT_Emp TO FILE = 'C:\SSLCert\TDECertificate.cer' WITH PRIVATE KEY( FILE = 'C:\SSLCert\TDECertificate.key', ENCRYPTION BY PASSWORD = 'Pa$$w0rd') GO --Database暗号化状況確認する USE [master] GO SELECT DB_NAME(database_id) as DBNAME,encryption_state FROM [sys].[dm_database_encryption_keys] --SQL Server 2019 CTP2.4、スキャン停止、停止の条件は、Scanしていること USE [JSSUG_DEV] GO ALTER DATABASE [JSSUG_DEV] SET ENCRYPTION SUSPEND GO --SQL Server 2019 CTP2.4、スキャン再開 USE [JSSUG_DEV] GO ALTER DATABASE [JSSUG_DEV] SET ENCRYPTION RESUME GO --SQL Server 2019 CTP2.4、スキャン状態確認 SELECT encryption_scan_state,encryption_scan_state_desc,encryption_scan_modify_date FROM sys.dm_database_encryption_keys -- Cleanup USE [JSSUG_DEV] GO ALTER DATABASE [JSSUG_DEV] SET ENCRYPTION OFF GO USE [JSSUG_DEV] GO DROP DATABASE ENCRYPTION KEY GO USE [master] GO DROP CERTIFICATE [CERT_Emp] GO USE [master] GO DROP MASTER KEY GO USE [JSSUG_DEV] GO DROP TABLE Employees GO |
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 |
/*************** Always Encrypted ***************/ USE [JSSUG_DEV] GO --Drop sample table DROP TABLE Employees GO -- Create sample table CREATE TABLE Employees ( EmployeeID INT PRIMARY KEY, EmployeeName VARCHAR(300), Position VARCHAR(100), Salary VARCHAR(100) ) GO -- Insert data INSERT Employees VALUES (1, 'Aさん', 'CTO', '$100000') INSERT Employees VALUES (2, 'Bさん', 'CIO', '$200000') INSERT Employees VALUES (3, 'Cさん', 'CEO', '$300000') GO --データ確認 SELECT * FROM Employees --ここからUI --AE接続オプション有効でInsert(パラメータ化なし) INSERT INTO Employees([EmployeeID],[EmployeeName],[Position],[Salary]) VALUES (4,'Dさん', 'FTE', '$400000') --パラメータ化でInsertする --クエリ実行オプションのAEパラメータ有効化にしてから実行すること。SSMS Ver17以降 DECLARE @EmployeeID INT = (SELECT MAX(EmployeeID) FROM Employees) + 1 DECLARE @EmployeeName VARCHAR(300) = 'Dさん' DECLARE @Position VARCHAR(100) = 'FTE' DECLARE @Salary VARCHAR(100) = '$400000' INSERT INTO Employees([EmployeeID],[EmployeeName],[Position],[Salary]) VALUES(@EmployeeID,@EmployeeName,@Position,@Salary) --データ確認 SELECT * FROM Employees --Clean Up USE [JSSUG_DEV] GO DROP TABLE [dbo].[Employees] GO DROP COLUMN ENCRYPTION KEY [CEK_Auto1] GO DROP COLUMN MASTER KEY [CMK_Auto1] GO --CUIでAEの設定 --CMK作成、証明書ストアから選ぶ USE [JSSUG_DEV] GO CREATE COLUMN MASTER KEY [CMK] WITH ( KEY_STORE_PROVIDER_NAME = N'MSSQL_CERTIFICATE_STORE', KEY_PATH = N'LocalMachine/My/B379C2D46AF0CE3EFF2DAD9BA73CB3492319B58F' ) GO --CEK作成、CMKでCEKを保護する USE [JSSUG_DEV] GO CREATE COLUMN ENCRYPTION KEY [CEK] WITH VALUES ( COLUMN_MASTER_KEY = [CMK], ALGORITHM = 'RSA_OAEP', ENCRYPTED_VALUE = 0x01700000016C006F00630061006C006D0061006300680069006E0065002F006D0079002F006200330037003900630032006400340036006100660030006300650033006500660066003200640061006400390062006100370033006300620033003400390032003300310039006200350038006600B73081592008A191A384CD285CA144E55ADE429E3FD897EDEE949F88B9FA32089423B60117AC15064AF725BCF638A934ADA6878CC3F7508D5F75B6B4E3AC75413B81D0967EBE4C5C58A45D61348F0810CB3F7DEC22FD347A8D633C3F37FDAD82256D91406FB54DB417341771A79884C9421104FDDEB3991B64036AF61E2948E664F01A81DE37981661CC1618F095DE072A966E6EA11DB3086E49C964AE2E3D3F9D05B4B6889E5FD292ED7B16BB604443C8CB2537EB144CA2107F7B071596410AC7D5031DC195E3EE9B065B83403A37CEA2B47C067C8BF025134CFFFEA49172F15B17ACAB0C4097E5DBADCBB622DD2F52358FA41D4A6EEC2CBB0596619D8D04F77B6C28D03F05FCA45ECA2101C609B9B724D8149FA91F3A85B872C5FFB92B3F58BC20FC6A72AB6CAD64740838DFED999387868F8E9F4AE4DF252013D3AD15A649DD211FFF95C04F142002DD5978B58890897DBE089949895E1902AC8C3F846948991717E46EDA434F6CC599A8BB7A906833F2334158BD9E3C2D9682D0137C3E270A9C93B6AE06BAF61D7C1B68159E01D9A3676380B814226102D56CC77957179FF90DF7868225A9DAC1BE7EEA5B4667B64409570E09308FA5FE49B03218E77B2EED80DE7D5DE3D0F8019850830C067D21ACD98DD846AA0A1308605B68EBBFEB30EBC520F4841A80D001CFA4F6D8AFA1CDCE0E756BAF8804AF528B9E8D2D0F1B36 ) GO --Drop sample table DROP TABLE Employees GO -- Create sample table CREATE TABLE Employees ( EmployeeID INT PRIMARY KEY, EmployeeName VARCHAR(300), Position VARCHAR(100), Salary VARCHAR(100) ENCRYPTED WITH (COLUMN_ENCRYPTION_KEY = [CEK], ENCRYPTION_TYPE = Randomized, ALGORITHM = 'AEAD_AES_256_CBC_HMAC_SHA_256') NOT NULL ) GO --パラメータ化でInsertする --クエリ実行オプションのAEパラメータ有効化にしてから実行すること。SSMS Ver17以降 DECLARE @EmployeeID INT = (SELECT ISNULL(MAX(EmployeeID),0) FROM Employees) + 1 DECLARE @EmployeeName VARCHAR(300) = 'Dさん' DECLARE @Position VARCHAR(100) = 'FTE' DECLARE @Salary VARCHAR(100) = '$400000' INSERT INTO Employees([EmployeeID],[EmployeeName],[Position],[Salary]) VALUES(@EmployeeID,@EmployeeName,@Position,@Salary) --データ確認 SELECT * FROM Employees --Clean Up USE [JSSUG_DEV] GO DROP TABLE [dbo].[Employees] GO DROP COLUMN ENCRYPTION KEY [CEK] GO DROP COLUMN MASTER KEY [CMK] GO |
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 |
/*************** Backup Encrypted ***************/ USE [JSSUG_DEV] GO --Drop sample table DROP TABLE Employees GO -- Create sample table CREATE TABLE Employees ( EmployeeID INT PRIMARY KEY, EmployeeName VARCHAR(300), Position VARCHAR(100), Salary VARCHAR(100) ) GO -- Insert data INSERT Employees VALUES (1, 'Aさん', 'CTO', '$100000') INSERT Employees VALUES (2, 'Bさん', 'CIO', '$200000') INSERT Employees VALUES (3, 'Cさん', 'CEO', '$300000') GO --データ確認 SELECT * FROM Employees --インスタンスレベルServiceMasterKey(ServiceMasterkey)、確認してから実行してください。 USE [master] GO IF NOT EXISTS( SELECT * FROM sys.symmetric_keys WHERE name = '##MS_ServiceMasterKey##') BEGIN CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'Pa$$w0rd' END GO --インスタンスレベルマスタキーを作成、確認してから実行してください。 USE [master] GO IF NOT EXISTS( SELECT * FROM sys.symmetric_keys WHERE name = '##MS_DatabaseMasterKey##') BEGIN CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'Pa$$w0rd' END GO -- Create CERTIFICATE --ここで、自己証明書を作っても問題ない USE [master] GO IF NOT EXISTS (SELECT * FROM sys.certificates WHERE name = 'CERT_Emp') BEGIN CREATE CERTIFICATE CERT_Emp FROM FILE = 'C:\SSLCert\PVK_4.cer' WITH PRIVATE KEY (FILE = 'C:\SSLCert\PVK_4.pvk', DECRYPTION BY PASSWORD = 'Pa$$w0rd') END GO --暗号化バックアップ BACKUP DATABASE [JSSUG_DEV] TO DISK = N'C:\Program Files\Microsoft SQL Server\MSSQL15.MSSQLSERVER\MSSQL\Backup\JSSUG_DEV_BE.bak' WITH FORMAT, INIT, MEDIADESCRIPTION = N'JSSUG_DEV BE', MEDIANAME = N'JSSUG_DEV MediaSet', NAME = N'JSSUG_DEV-完全 データベース バックアップ', SKIP, NOREWIND, NOUNLOAD, COMPRESSION, ENCRYPTION(ALGORITHM = AES_256, SERVER CERTIFICATE = [CERT_Emp]), STATS = 10, CHECKSUM GO |