共用方式為


加密資料行

此主題描述如何使用 Transact-SQL,在 SQL Server 2012 中透過對稱加密來加密資料行。

本主題內容

  • 開始之前:

    安全性

  • 若要使用 Transact-SQL 來加密資料行

開始之前

安全性

權限

需要下列權限,才能執行以下步驟:

  • 資料庫的 CONTROL 權限。

  • 資料庫的 CREATE CERTIFICATE 權限。 只有 Windows 登入、SQL Server 登入,以及應用程式角色可以擁有憑證。 群組和角色無法擁有憑證。

  • 資料表的 ALTER 權限。

  • 金鑰的某種權限,而且絕不能被拒絕 VIEW DEFINITION 權限。

搭配回到頁首連結使用的箭頭圖示[Top]

使用 Transact-SQL

若要使用簡單的對稱加密來加密資料行

  1. [物件總管] 中,連接到 Database Engine 的執行個體。

  2. 在標準列上,按一下 [新增查詢]

  3. 將下列範例複製並貼到查詢視窗中,然後按一下 [執行]

    USE AdventureWorks2012;
    --If there is no master key, create one now. 
    IF NOT EXISTS 
        (SELECT * FROM sys.symmetric_keys WHERE symmetric_key_id = 101)
        CREATE MASTER KEY ENCRYPTION BY 
        PASSWORD = '23987hxJKL95QYV4369#ghf0%lekjg5k3fd117r$$#1946kcj$n44ncjhdlj'
    GO
    
    CREATE CERTIFICATE Sales09
       WITH SUBJECT = 'Customer Credit Card Numbers';
    GO
    
    CREATE SYMMETRIC KEY CreditCards_Key11
        WITH ALGORITHM = AES_256
        ENCRYPTION BY CERTIFICATE Sales09;
    GO
    
    -- Create a column in which to store the encrypted data.
    ALTER TABLE Sales.CreditCard 
        ADD CardNumber_Encrypted varbinary(128); 
    GO
    
    -- Open the symmetric key with which to encrypt the data.
    OPEN SYMMETRIC KEY CreditCards_Key11
       DECRYPTION BY CERTIFICATE Sales09;
    
    -- Encrypt the value in column CardNumber using the
    -- symmetric key CreditCards_Key11.
    -- Save the result in column CardNumber_Encrypted.  
    UPDATE Sales.CreditCard
    SET CardNumber_Encrypted = EncryptByKey(Key_GUID('CreditCards_Key11')
        , CardNumber, 1, HashBytes('SHA1', CONVERT( varbinary
        , CreditCardID)));
    GO
    
    -- Verify the encryption.
    -- First, open the symmetric key with which to decrypt the data.
    
    OPEN SYMMETRIC KEY CreditCards_Key11
       DECRYPTION BY CERTIFICATE Sales09;
    GO
    
    -- Now list the original card number, the encrypted card number,
    -- and the decrypted ciphertext. If the decryption worked,
    -- the original number will match the decrypted number.
    
    SELECT CardNumber, CardNumber_Encrypted 
        AS 'Encrypted card number', CONVERT(nvarchar,
        DecryptByKey(CardNumber_Encrypted, 1 , 
        HashBytes('SHA1', CONVERT(varbinary, CreditCardID))))
        AS 'Decrypted card number' FROM Sales.CreditCard;
    GO
    

若要使用包含驗證器的對稱加密來加密資料行

  1. [物件總管] 中,連接到 Database Engine 的執行個體。

  2. 在標準列上,按一下 [新增查詢]

  3. 將下列範例複製並貼到查詢視窗中,然後按一下 [執行]

    USE AdventureWorks2012;
    GO
    
    --If there is no master key, create one now. 
    IF NOT EXISTS 
        (SELECT * FROM sys.symmetric_keys WHERE symmetric_key_id = 101)
        CREATE MASTER KEY ENCRYPTION BY 
        PASSWORD = '23987hxJKL969#ghf0%94467GRkjg5k3fd117r$$#1946kcj$n44nhdlj'
    GO
    
    CREATE CERTIFICATE HumanResources037
       WITH SUBJECT = 'Employee Social Security Numbers';
    GO
    
    CREATE SYMMETRIC KEY SSN_Key_01
        WITH ALGORITHM = AES_256
        ENCRYPTION BY CERTIFICATE HumanResources037;
    GO
    
    USE [AdventureWorks2012];
    GO
    
    -- Create a column in which to store the encrypted data.
    ALTER TABLE HumanResources.Employee
        ADD EncryptedNationalIDNumber varbinary(128); 
    GO
    
    -- Open the symmetric key with which to encrypt the data.
    OPEN SYMMETRIC KEY SSN_Key_01
       DECRYPTION BY CERTIFICATE HumanResources037;
    
    -- Encrypt the value in column NationalIDNumber with symmetric 
    -- key SSN_Key_01. Save the result in column EncryptedNationalIDNumber.
    UPDATE HumanResources.Employee
    SET EncryptedNationalIDNumber = EncryptByKey(Key_GUID('SSN_Key_01'), NationalIDNumber);
    GO
    
    -- Verify the encryption.
    -- First, open the symmetric key with which to decrypt the data.
    OPEN SYMMETRIC KEY SSN_Key_01
       DECRYPTION BY CERTIFICATE HumanResources037;
    GO
    
    -- Now list the original ID, the encrypted ID, and the 
    -- decrypted ciphertext. If the decryption worked, the original
    -- and the decrypted ID will match.
    SELECT NationalIDNumber, EncryptedNationalIDNumber 
        AS 'Encrypted ID Number',
        CONVERT(nvarchar, DecryptByKey(EncryptedNationalIDNumber)) 
        AS 'Decrypted ID Number'
        FROM HumanResources.Employee;
    GO
    

如需詳細資訊,請參閱下列內容:

搭配回到頁首連結使用的箭頭圖示[Top]