welcome to XRM blog

Keep in touch with latest CRM/ERP articles

To remain competitive your organisation must be efficient across the business process spectrum. To do so you need to take sound decisions based on a balance between the cost and risk. To do so you will be heavily dependent on your content management in itself needs...

image
Blog
Term: SQL Server 2012
1 found

MS CRM 2011 Unable to restore SQL Server enterprise database to SQL Server 2012

By xrmlabs webmaster on 1/18/2013
Hi All,

Few days back we were migrating our MS CRM 2011 databases from SQL Server 2008 to SQL Server 2012 edition when we we encountered the following problem.


Database 'YOURORG_MSCRM' cannot be started in this edition of SQL Server because it contains a partition function 'AuditPFN'. Only Enterprise edition of SQL Server supports partitioning.
Database 'YOURORG_MSCRM' cannot be started because some of the database functionality is not available in the current edition of SQL Server. (Microsoft SQL Server, Error: 905)
 


After searching a bit on the web I found that this problem is causes if your were using MS CRM 2011 on SQL server Enterprise edition. MS CRM 2011 creates a partition for Audit when running on SQL server enterprise edition. To solve this problem you will have to drop indexes and other references from the MS CRM SQL Server database.

For doing so please use the following command. Before executing the following command I will strongly recommend that you back up your database and restore it with a different name and then try the following command on the new database instance.


IF EXISTS (SELECT name FROM sys.partition_schemes WHERE name='AuditPScheme')
BEGIN
 SELECT
  CASE WHEN ind.type != 1
   THEN
    'DROP INDEX [dbo].[AuditBase].' + QUOTENAME(ind.name) + ' '
   ELSE ' '
  END +
  'CREATE ' + CASE is_unique WHEN 1 THEN 'UNIQUE ' ELSE '' END  +
  ind.type_desc + ' INDEX ' + QUOTENAME(ind.name  COLLATE SQL_Latin1_General_CP1_CI_AS )  + ' ON [dbo].' +  QUOTENAME(OBJECT_NAME(object_id)) + ' (' +
    
  REVERSE(SUBSTRING(REVERSE((
   SELECT name + CASE WHEN sc.is_descending_key = 1 THEN ' DESC' ELSE ' ASC' END + ','
   FROM
    sys.index_columns sc
    JOIN sys.columns c ON sc.object_id = c.object_id AND sc.column_id = c.column_id
   WHERE
    OBJECT_NAME(sc.object_id) = 'AuditBase' AND
    sc.object_id = ind.object_id AND
    sc.index_id = ind.index_id
   ORDER BY index_column_id ASC
   FOR XML PATH('')
        )), 2, 8000)) + ')' +
  CASE WHEN ind.type = 1
   THEN
    ' WITH (DROP_EXISTING = ON) ON [PRIMARY]'
   ELSE
    ' '
  END  as Script
 INTO #indexesScript
 FROM sys.indexes ind
 JOIN sys.partition_schemes ps on ind.data_space_id=ps.data_space_id
 WHERE
  OBJECT_NAME(object_id) = 'AuditBase'
  AND ps.name = 'AuditPScheme'
  AND is_unique_constraint = 0
 SELECT * FROM #indexesScript
  
 DECLARE @recreateScript nvarchar(max)
 DECLARE indScript CURSOR FOR
 SELECT Script FROM #indexesScript
 OPEN indScript
 FETCH NEXT FROM indScript INTO @recreateScript
  
 WHILE @@FETCH_STATUS = 0  
 BEGIN  
  BEGIN TRANSACTION t1
  Execute sp_executesql @recreateScript
   
  IF @@ERROR > 0
  BEGIN
   ROLLBACK TRAN t1
   declare @message varchar(max)
   set @message = 'Audit history recreate index failed. SQL: ' + @recreateScript
      RAISERROR (@message, 10,1)
  END
  ELSE
  BEGIN
   COMMIT TRAN
  END
  FETCH NEXT FROM indScript INTO @recreateScript  
 END  
 DROP PARTITION SCHEME AuditPScheme
 DROP PARTITION FUNCTION AuditPFN
   
 CLOSE indScript  
 DEALLOCATE indScript
 DROP TABLE #indexesScript
END


Running the above script will give you the following output.

CREATE UNIQUE CLUSTERED INDEX [cndx_PrimaryKey_Audit] ON [dbo].[AuditBase] (CreatedOn DESC,AuditId DESC) WITH (DROP_EXISTING = ON) ON
DROP INDEX [dbo].[AuditBase].[ndx_PrimaryKey_Audit] CREATE NONCLUSTERED INDEX [ndx_PrimaryKey_Audit] ON [dbo].[AuditBase] (AuditId ASC,CreatedOn DESC)
DROP INDEX [dbo].[AuditBase].[ndx_ObjectId] CREATE NONCLUSTERED INDEX [ndx_ObjectId] ON [dbo].[AuditBase] (ObjectId ASC,CreatedOn DESC)
DROP INDEX [dbo].[AuditBase].[ndx_UserId] CREATE NONCLUSTERED INDEX [ndx_UserId] ON [dbo].[AuditBase] (UserId ASC,CreatedOn DESC)
DROP INDEX [dbo].[AuditBase].[fndx_ObjectTypeCode] CREATE NONCLUSTERED INDEX [fndx_ObjectTypeCode] ON [dbo].[AuditBase] (ObjectTypeCode ASC,CreatedOn DESC)
DROP INDEX [dbo].[AuditBase].[ndx_SystemManaged_Audit] CREATE NONCLUSTERED INDEX [ndx_SystemManaged_Audit] ON [dbo].[AuditBase] (CallingUserId ASC,Action ASC,Operation ASC,CreatedOn DESC)


Once done now you can backup the database and it will be restored without any problem on SQL Server 2012

For more information please refer to
Hope this helps 
SQL Sever
MS CRM 2011
SQL Server 2008
SQL Server 2012
Blog Calendar
Blog Calendar List
2019 Jan  18  3
2018 Dec  25  4
2018 Nov  57  3
2018 Oct  12  3
2018 Sep  51  11
2018 Aug  4  2
2018 Jun  11  1
2018 Jan  47  2
2017 Sep  471  5
2017 Aug  15  1
2017 Jul  15  2
2017 Jun  42  2
2017 May  17  1
2017 Apr  31  2
2017 Mar  108  4
2017 Feb  341  4
2016 Dec  174  3
2016 Nov  306  8
2016 Oct  217  10
2016 Sep  352  6
2016 Aug  38  1
2016 Jun  1671  6
2016 May  103  3
2016 Jan  68  2
2015 Dec  382  6
2015 Nov  3  1
2015 Oct  12  1
2015 Sep  1223  6
2015 Aug  12  1
2015 Jul  111  2
2015 Jun  8  1
2015 May  20  1
2015 Apr  21  2
2015 Mar  69  3
2015 Jan  5091  4
2014 Dec  15  1
2014 Nov  2181  4
2014 Oct  75  2
2014 Sep  97  2
2014 Aug  3252  1
2014 Jul  41  2
2014 Apr  2429  12
2014 Mar  271  19
2014 Feb  221  8
2014 Jan  1510  16
2013 Dec  21  2
2013 Nov  616  2
2013 Oct  246  3
2013 Sep  10  1
2013 Aug  29  3
2013 Jul  202  1
2013 Apr  45  6
2013 Mar  1716  10
2013 Feb  288  4
2013 Jan  255  2
2012 Nov  27  2
2012 Oct  410  10
Tag Cloud
Interested in our services? Still not sure about project details? get a quote