web
You’re offline. This is a read only version of the page.
close
Skip to main content

Notifications

Announcements

No record found.

Community site session details

Community site session details

Session Id :
Finance | Project Operations, Human Resources, ...
Suggested Answer

Management Reporter - Database Restored to New SQL, Cannot connect now.

(0) ShareShare
ReportReport
Posted on by 225

Hello everyone.

Has an issue with the SQL server where we pretty much had to rebuild it, All database were able to get re-attached and all applications are working, except MR.  The issue we are having now is with Management Reporter. When trying to re-connect the existing database in the configuration console I am receiving the following error:

"Please create a master key in the database or open the master key in the session before performing this operation. The "DecryptData" procedure attempted to return a status of NULL this is not allowed. A status of 0 will be returned instead. Originating procedure, DecryptData.

Saw this https://support.microsoft.com/en-us/help/2744330/error-messages-when-you-restore-a-microsoft-management-reporter-2012-d but without the building blocks I cannot proceed. 

I do now know the key for this and do not have the building blocks. 

Any help would be appreciated./ 

I have the same question (0)
  • Suggested answer
    Ludwig Reinhard Profile Picture
    Microsoft Employee on at

    Hi,

    You refer to no. 8 in the website that you shared, right?

    The building blocks contain the rows, columns, reporting trees and report setups that you have made in the past.

    If you have not designed any new report then there might be nothing available there and you don't have to worry about this step.

    Best regards,

    Ludwig

  • guk1964 Profile Picture
    10,888 on at

    Is there no sql back up of MR you can restore, and then refresh the data? or recover the password?

    MR should have its own SQl instance because its configuration is different.

    When you move the database to another server, you lose the ability to automatically decrypt and open the database master key because the local server key will most likely be different. If you can't decrypt the database master key, then you can't decrypt anything else that depends on it (certificates, symmetric keys, etc).

    The problem occurs for example when restoring an MR database.

    It can also occur when the Management Reporter database is in an availability group Always On (Availability group) when you switch the Management Reporter database to the secondary server, it will not be able to decrypt the data of the database. Consequently, the DataMart database disappears from the console and the following error message appears in the event log:

    For MR :

    1. Key Service (SMK) - Generated  by the SQL service is used to encrypt the Database Master Key (DMK).
    2. Database Master Key (DMK) – is used to encrypt the certificate.
    3. Certificate – is used to encrypt the symmetric key
    4. Symmetric Key – is used to encrypt data

    The problem is that the Service Key (SMK) of the second SQL server is not able to decrypt the Database Master Key (DMK) located in a database Management Reporter since it was encrypted with the Key Service the primary server. Because SQL is not able to open the DMK, it therefore cannot open the certificate, etc .

    There links may help"

    https://support.microsoft.com/en-ca/help/2744330/error-messages-when-you-restore-a-microsoft-management-reporter-2012-d

    https://docs.microsoft.com/en-us/sql/t-sql/statements/open-master-key-transact-sql?view=sql-server-ver15

    https://docs.microsoft.com/en-us/sql/t-sql/statements/alter-master-key-transact-sql?view=sql-server-ver15

    https://docs.microsoft.com/en-us/sql/t-sql/statements/restore-master-key-transact-sql?redirectedfrom=MSDN&view=sql-server-ver15

    https://docs.microsoft.com/en-us/sql/relational-databases/security/encryption/restore-the-service-master-key?view=sql-server-ver15

    https://docs.microsoft.com/en-us/sql/t-sql/statements/backup-service-master-key-transact-sql?view=sql-server-ver15

    https://docs.microsoft.com/en-us/sql/relational-databases/security/encryption/back-up-the-service-master-key?view=sql-server-ver15

      I  recommend to add a new password on the production system using ALTER MASTER KEY (msdn2.microsoft.com/.../ms186937.aspx) in case the original password is truly lost.

    OPEN MASTER KEY DECRYPTION BY PASSWORD = 'SQLAuthority' ALTER MASTER KEY ADD ENCRYPTION BY SERVICE MASTER KEY

    The REGENERATE option should be used only when you want to have a new master key in the database

    ALTER MASTER KEY DROP ENCRYPTION BY SERVICE MASTER KEY.

    When SQL requires a Database Master Key (DMK) to encrypt or decrypt a key, SQL tries to decrypt the DMK from the Service Master Key (SMK). If this fails,then  SQL checks whether the password to open the DMK is in sys.master_key_passwords.

    Add the password to the DMK ManagementReporter catalog sys.master_key_passwords for all servers in the group.

    EXEC sp_control_dbmasterkey_password @db_name = N'ManagementReporter ' , 

        @password = xxxxxxxxx ' , @action = Do not add' ;

    https://docs.microsoft.com/en-us/sql/relational-databases/system-stored-procedures/sp-control-dbmasterkey-password-transact-sql?view=sql-server-ver15

    The RESTORE MASTER KEY with FORCE option to replace the DBMK - needs care -   make sure you have backed up any important data you have modified. The service master key is the root of the SQL Server encryption hierarchy. The service master key directly or indirectly secures all other keys in the tree. If a dependent key cannot be decrypted during a forced restore, data that is secured by that key will be lost.

    ,

Under review

Thank you for your reply! To ensure a great experience for everyone, your content is awaiting approval by our Community Managers. Please check back later.

Helpful resources

Quick Links

Responsible AI policies

As AI tools become more common, we’re introducing a Responsible AI Use…

Neeraj Kumar – Community Spotlight

We are honored to recognize Neeraj Kumar as our Community Spotlight honoree for…

Leaderboard > Finance | Project Operations, Human Resources, AX, GP, SL

#1
Martin Dráb Profile Picture

Martin Dráb 660 Most Valuable Professional

#2
André Arnaud de Calavon Profile Picture

André Arnaud de Cal... 549 Super User 2025 Season 2

#3
Sohaib Cheema Profile Picture

Sohaib Cheema 307 User Group Leader

Last 30 days Overall leaderboard

Product updates

Dynamics 365 release plans