How to copy encrypted data to another database

  • I have two databases that need to share encrypted data. I created a master key in both databases (both using the same password), then created a certificate in both (same name). When I copy encrypted data from one database into the other, the other is unable to decrypt the data.

    I know that I can decrypt the data from one before putting it into the other, and then run the encryption in the new database, but I would rather not have to decrypt the data before sending it to the new database.

    Does anyone know of a way to make the databases share the same master key and/or certificate so I don't have to play games while copying data? Right now I'm using only SQL Server certificates, not third party certificates. I'd rather not have to use a third-party cert if I can help it.

    Thanks,

    Desiree

  • This post should be under the security forum.

    I think the issue is that the database master key is encrypted with the service master key, which is then used to encrypt the certs and/or symmetric keys in the database. Even though the database master key may be the same they are not encrypted the same unless you are sharing the same service certs for both servers.

    Try opening the master key in the database that is not decrypting successfully and reencrypting and see if it works:

    OPEN MASTER KEY DECRYPTION BY PASSWORD = 'YourPassword'

    ALTER MASTER KEY REGENERATE WITH ENCRYPTION BY PASSWORD = 'YourPassword'

    CLOSE MASTER KEY

    open symmetric key YourKeyName

    DECRYPTION BY certificate YourCertname

    select top 20

    cast(decryptByKey(YourEncryptedFieldName) as varchar(8000))

    ,cast(decryptByKey(YourEncryptedFieldName) as varchar(8000))

    ,*

    from YourTableName

    CLOSE ALL SYMMETRIC KEYS

  • I think you're close.

    Rather than creating a certificate with the same name in both databases you should backup the certificate from the first database and restore that to the second.

    USE DB1

    CREATE CERTIFICATE cert1 WITH SUBJECT = 'Certificate for my stuff'

    BACKUP CERTIFICATE cert1 TO FILE = 'c:\cert1.dat'

    WITH PRIVATE KEY

    (

    ENCRYPTION BY PASSWORD = 'mypassword',

    FILE = 'c:\cert1_privatekey.dat'

    )

    --

    USE DB2

    CREATE CERTIFICATE cert1 FROM FILE = 'c:\cert1.dat'

    WITH PRIVATE KEY

    (

    FILE = 'c:\cert1_privatekey.dat',

    DECRYPTION BY PASSWORD = 'mypassword'

    )

  • Toby White - Thursday, April 22, 2010 2:17 PM

    This post should be under the security forum.I think the issue is that the database master key is encrypted with the service master key, which is then used to encrypt the certs and/or symmetric keys in the database. Even though the database master key may be the same they are not encrypted the same unless you are sharing the same service certs for both servers. Try opening the master key in the database that is not decrypting successfully and reencrypting and see if it works:OPEN MASTER KEY DECRYPTION BY PASSWORD = 'YourPassword'ALTER MASTER KEY REGENERATE WITH ENCRYPTION BY PASSWORD = 'YourPassword'CLOSE MASTER KEYopen symmetric key YourKeyNameDECRYPTION BY certificate YourCertname select top 20 cast(decryptByKey(YourEncryptedFieldName) as varchar(8000)) ,cast(decryptByKey(YourEncryptedFieldName) as varchar(8000)) ,*from YourTableName CLOSE ALL SYMMETRIC KEYS

    Sorry to bring this thread back to life. I have a slightly similar issue. 

    Am I correct in assuming that you have assumed that the OP wanted to restore it to different server.

    My question is this. If I am restoring a database on the same server with encrypted columns using symmetric keys, then I do not need to do any of that do I? as symmetric key is restored and so is DBMK? and I can just happily go and open key and decrypt....?????????

  • if your database has already been restored you should be able
    OPEN MASTER KEY DECRYPTION BY PASSWORD = 'MyStrongPassword';
    ALTER MASTER KEY
        ADD ENCRYPTION BY SERVICE MASTER KEY;
    CLOSE MASTER KEY;

    where "MyStrongPassword" is the pw from the source database

  • Bert-701015 - Wednesday, February 7, 2018 7:36 AM

    if your database has already been restored you should be able
    OPEN MASTER KEY DECRYPTION BY PASSWORD = 'MyStrongPassword';
    ALTER MASTER KEY
        ADD ENCRYPTION BY SERVICE MASTER KEY;
    CLOSE MASTER KEY;

    where "MyStrongPassword" is the pw from the source database

    Do I have to re-encrypt my DBMK with SMK? if so I am assuming that's because no two databases can have exactly the same DBMK. But then that would beg the question that when my DBMK changes then my symmetric key will stop working because now my symmetric key is dealing with a different DBMK which was used to create it. And if all i have said is true ( I hope I am wrong) then i think i can only encrypt new data but cannot decrypt restored data as my DBMK is now different?????????????

    Regards,

    Waqar

  • In our case, we have two databases on the same instance.  DB1 has encrypted data.  DB2 accesses DB1 data via a view.  The above code allowed for the retrieval of the data decrypted.  In your case, the database master key should already be there (via the restore).  Run this to verify:use DBNAME;
    select * from sys.symmetric_keys

    Looks like should not have to do anything.

  • Many Thanks. I have just tested and looks like we dont have to do any thing:). That's a first btw as there is always something twisted somewhere.:)

Viewing 8 posts - 1 through 7 (of 7 total)

You must be logged in to reply to this topic. Login to reply