├── LICENSE.md ├── README.md └── src ├── All └── KenticoShrinkSQLLogFile.sql ├── KX08 └── KenticoDeleteOMContact.v8.sql ├── KX11-12-Upgrade └── PREUPGRADE-0-Remove-GoogleUrl-SubKeys.sql ├── KX11 ├── KenticoCleanUpWebFarmServersAndTasks.v11.sql ├── KenticoClearObjectVersionHistory.v11.sql ├── KenticoClearVersionHistoryAndAttachmentHistory-STAGING-SAFE.v11.sql ├── KenticoClearVersionHistoryAndAttachmentHistory.v11.sql ├── KenticoDeleteAnalyticsData-ByDays.v11.sql ├── KenticoDeleteAnalyticsData.v11.sql ├── KenticoDeleteCOMOrdersInBulk.v11.sql ├── KenticoDeleteStagingData.v11.sql └── KenticoDisableTasksForDevSpinup.v11.sql ├── KX12-to-13-Upgrade ├── PostUpgrade │ ├── Dynamic-Routing-Migration │ │ └── Instructions.md │ ├── POST-0-Table-ColumnChecks.sql │ ├── POST-1-Constraint-Check.sql │ ├── POST-2-ViewChecks.sql │ └── POST-3-StoredProcFunctionsCheck.sql └── PreUpgrade │ ├── Check-And-Convert-PageTypes-Queries.sql │ ├── Convert-Container-PageTypes-To-CoupledWithUrl.sql │ ├── Convert-Site-To-Content-Only.sql │ ├── PREUPGRADE-0-Clear-UIElements.sql │ ├── PREUPGRADE-1-Clear-Resources.sql │ ├── PREUPGRADE-2-Remove-Templates.sql │ ├── PREUPGRADE-3-DropStyleSheets.sql │ ├── PREUPGRADE-4-CreateMissingConstraints.sql │ ├── PREUPGRADE-5-SetCompatabilityLevel.sql │ └── PREUPGRADE-6-RemovePMTables.sql ├── KX12 ├── KenticoCheckUrlPatternsForUpgrade.v12.sql ├── KenticoCleanUpWebFarmServersAndTasks.v12.sql ├── KenticoClearObjectVersionHistory.v12.sql ├── KenticoClearVersionHistoryAndAttachmentHistory-STAGING-SAFE.v11.sql ├── KenticoClearVersionHistoryAndAttachmentHistory.v12.sql ├── KenticoConvertContainerPageTypeToCoupled.v12.sql ├── KenticoDeleteAnalyticsData-ByDays.v12.sql ├── KenticoDeleteAnalyticsData.v12.sql ├── KenticoDeleteCOMOrdersInBulk.v12.sql ├── KenticoDeleteStagingData.v12.sql └── KenticoDisableTasksForDevSpinup.v12.sql ├── KX13 ├── ConvertContainerPageTypeToCoupledWithUrl.v12.sql ├── ConvertPageTypeToUrl.sql ├── GetAllResourceStringsForEveryLanguageOnTheSite.v13.sql ├── Manual-OM-DBSeparation │ ├── 1-Remove-Procedures.sql │ ├── 2-Remove-Views.sql │ ├── 3-Remove-OM-Foreign-Keys.sql │ ├── 4-Remove-Other-Foreign-Key.sql │ ├── 5-Remove-Tables.sql │ ├── 6-Remove-Functions.sql │ ├── 7-Remove-Table-Types.sql │ ├── Cleanup-1-Remove-OM-Tables.sql │ ├── Cleanup-2-Remove-OM-Functions.sql │ ├── Cleanup-3-Remove-OM-Views.sql │ ├── Cleanup-4-Remove-OM-Stored-Procedures.sql │ └── readme.md └── SetPageTemplatesOnMissingNodes.sql └── KX9-10-Upgrade └── PREUPGRADE-0-Truncate-Ecommerce-Phones.sql /LICENSE.md: -------------------------------------------------------------------------------- 1 | This is free and unencumbered software released into the public domain. 2 | 3 | Anyone is free to copy, modify, publish, use, compile, sell, or 4 | distribute this software, either in source code form or as a compiled 5 | binary, for any purpose, commercial or non-commercial, and by any 6 | means. 7 | 8 | In jurisdictions that recognize copyright laws, the author or authors 9 | of this software dedicate any and all copyright interest in the 10 | software to the public domain. We make this dedication for the benefit 11 | of the public at large and to the detriment of our heirs and 12 | successors. We intend this dedication to be an overt act of 13 | relinquishment in perpetuity of all present and future rights to this 14 | software under copyright law. 15 | 16 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, 17 | EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF 18 | MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. 19 | IN NO EVENT SHALL THE AUTHORS BE LIABLE FOR ANY CLAIM, DAMAGES OR 20 | OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, 21 | ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR 22 | OTHER DEALINGS IN THE SOFTWARE. 23 | 24 | For more information, please refer to 25 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Kentico Xperience SQL Utility Scripts 2 | 3 | A collection of SQL Scripts used to help maintain and work with Kentico Xperience (Kentico CMS) databases. But remember, with great power comes great responsibility. These scripts are only tested in a few environments. Make sure to test them out first in your development environment and please be sure to create a database backup before running for real. 4 | 5 | A few more details can be found at [https://www.mcbeev.com/Kentico-Xperience-SQL-Database-Scripts](https://www.mcbeev.com/Kentico-Xperience-SQL-Database-Scripts) 6 | -------------------------------------------------------------------------------- /src/All/KenticoShrinkSQLLogFile.sql: -------------------------------------------------------------------------------- 1 | /* KenticoShrinkSQLLogFile.sql */ 2 | /* Goal: Shrink your SQL Log file */ 3 | /* Description: reclaims space by shrinking */ 4 | /* the SQL ldf file (log file) */ 5 | /* Intended Kentico Verison: Any and all */ 6 | /* Author: Brian McKeiver (mcbeev@gmail.com) */ 7 | /* Revision: 1.0 */ 8 | 9 | /* For reference, show recovery models of all DBs */ 10 | SELECT [name], [recovery_model_desc] FROM sys.databases 11 | GO 12 | 13 | /* Step 1 - Change Recovery Model to Simple */ 14 | ALTER DATABASE [Your Database Name Here] SET RECOVERY SIMPLE; 15 | GO 16 | 17 | /* Step 2 - Release the marked space to OS */ 18 | DECLARE @DataFile SYSNAME, @LogFile SYSNAME; 19 | 20 | SELECT @DataFile = RTRIM(LTRIM(name)) FROM sys.database_files WHERE TYPE = 0; 21 | 22 | SELECT @LogFile = RTRIM(LTRIM(name)) FROM sys.database_files WHERE TYPE = 1; 23 | 24 | --DBCC Shrinkfile(@DataFile , 100); --If you want to shrink the data file too, uncomment this line 25 | DBCC Shrinkfile(@LogFile , 100); 26 | 27 | /* Step 3 - Change Recovery Model back to FULL */ 28 | ALTER DATABASE [Your Database Name Here] SET RECOVERY FULL; 29 | GO 30 | -------------------------------------------------------------------------------- /src/KX08/KenticoDeleteOMContact.v8.sql: -------------------------------------------------------------------------------- 1 | /* KenticoDeleteOMContact.v8.sql */ 2 | /* Goal: Clear out OM_Contact in bulk */ 3 | /* Description: Bulk delete OM_Contact data */ 4 | /* and all of the related FK data by date */ 5 | /* Intended Verison: Kentico 8.x */ 6 | /* Author: Brian McKeiver (mcbeev@gmail.com)*/ 7 | /* Revision: 1.0 */ 8 | /* Comment: Removing 10k rows took ~ 8 secs */ 9 | -- Read more at: https://www.mcbeev.com/Blog/February-2015/Ensure-Your-Kentico-EMS-Site-Is-Running-At-Peak-Performance 10 | 11 | DECLARE @imax INT 12 | DECLARE @i INT 13 | DECLARE @cnt INT 14 | DECLARE @batchSize INT 15 | DECLARE @whereParam NVARCHAR(max) 16 | DECLARE @StartDate DATETIME 17 | DECLARE @EndDate DATETIME 18 | 19 | --date range to remove data from, start small to make sure it works !! 20 | --SET @StartDate = DATEADD(yyyy, -2, DATEADD(dd, 1, GETDATE())) 21 | SET @StartDate = '2/14/2015' 22 | --SET @EndDate = DATEADD(yyyy, -1, DATEADD(dd, 1, GETDATE())) 23 | SET @EndDate = '2/14/2015' 24 | 25 | --How many to delete at a time, be careful! 26 | SET @batchSize = 10000 27 | 28 | --used for mass delete param 29 | SET @whereParam = '(ContactEmail IS NULL) AND (ContactCreated BETWEEN '''+ CAST(@StartDate as varchar(20)) +''' AND '''+ CAST(@EndDate as varchar(20)) +''')' 30 | 31 | --figure out how many times we need to loop to clear the data in bulk 32 | SELECT @cnt = Count(ContactID) FROM OM_Contact WHERE OM_Contact.ContactCreated BETWEEN @StartDate AND @EndDate And ContactEmail IS NULL 33 | 34 | PRINT 'Records found to delete based on searching ' + CAST(@StartDate as varchar(20)) + ' - ' + CAST(@EndDate as varchar(20)) + ' :' 35 | PRINT @cnt 36 | PRINT 'Starting to delete at: '+ CAST(GETDATE() as nvarchar) 37 | 38 | --figure out how many times we need to loop to clear the data in bulk, 39 | -- and make sure we have 1 extra iteration in case of less than 100 40 | SET @imax = (@cnt / @batchSize) + 1 41 | 42 | --loop counter 43 | SET @i = 1 44 | 45 | SET NOCOUNT ON; 46 | 47 | --release the kracken 48 | WHILE (@i <= @imax) 49 | BEGIN 50 | 51 | EXEC [Proc_OM_Contact_MassDelete] @whereParam, @batchSize 52 | 53 | PRINT 'Deleted batch: '+ CAST(@i as nvarchar) 54 | SET @i = @i + 1 55 | END 56 | 57 | PRINT 'Finished to delete at: '+ CAST(GETDATE() as nvarchar) 58 | PRINT 'Max Records deleted: ' + CAST(((@i - 1) * @batchSize) as nvarchar) -------------------------------------------------------------------------------- /src/KX11-12-Upgrade/PREUPGRADE-0-Remove-GoogleUrl-SubKeys.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------------------------------- 2 | -------- PRE UPGRADE Kentico 11 to Kentico 12 ------------ 3 | -------- Settings Foreign Key Fix ------------ 4 | -- Instances of Kentico Xperience that started before Kentico 10 may have -- 5 | -- foreign key dependencies that will cause sql errors during upgrade. This -- 6 | -- script should be ran just prior to running the upgrade script to foreign -- 7 | -- key dependencies. -- 8 | -- -- 9 | -- ALWAYS Backup before running these. Don't be THAT Guy -- 10 | -- Author: Trevor Fayas, version 1.0.0 -- 11 | ------------------------------------------------------------------------------- 12 | 13 | -- delete the children first. 14 | DECLARE @categoryParentID int; 15 | SET @categoryParentID = (SELECT TOP 1 [CategoryID] FROM [CMS_SettingsCategory] WHERE [CategoryName] = 'CMS.UrlShortening') 16 | IF @categoryParentID IS NOT NULL BEGIN 17 | 18 | DECLARE @categoryResourceID int; 19 | SET @categoryResourceID = (SELECT TOP 1 [ResourceID] FROM [CMS_Resource] WHERE [ResourceGUID] = 'aafd78f2-91f7-47cc-bf0b-d1a048d9540a') 20 | IF @categoryResourceID IS NOT NULL BEGIN 21 | 22 | -- Delete children settings keys 23 | delete from CMS_SettingsKey where KeyCategoryID in(select P.CategoryID from CMS_SettingsCategory P where [CategoryName] = 'CMS.UrlShortening.Googl' and P.CategoryParentID = @categoryParentID) 24 | 25 | -- Deletes the actual key 26 | DELETE FROM [CMS_SettingsCategory] WHERE [CategoryName] = 'CMS.UrlShortening.Googl' AND [CategoryParentID] = @categoryParentID 27 | 28 | END 29 | 30 | END 31 | 32 | -------------------------------------------------------------------------------- /src/KX11/KenticoCleanUpWebFarmServersAndTasks.v11.sql: -------------------------------------------------------------------------------- 1 | 2 | declare @server nvarchar(200), @serverid int 3 | set @server = '' 4 | 5 | select @serverid = serverid 6 | from cms_webfarmserver 7 | where servername = @server 8 | 9 | delete cms_webfarmserverlog 10 | where serverid = @serverid 11 | 12 | delete cms_webfarmservermonitoring 13 | where serverid = @serverid 14 | 15 | delete cms_webfarmservertask 16 | where serverid = @serverid 17 | 18 | delete cms_webfarmtask 19 | where TaskMachineName = @server 20 | 21 | delete cms_webfarmserver 22 | where serverid = @serverid 23 | -------------------------------------------------------------------------------- /src/KX11/KenticoClearObjectVersionHistory.v11.sql: -------------------------------------------------------------------------------- 1 | /* KenticoClearObjectVersionHistory.v11.sql */ 2 | /* Goal: Clean up data from objects */ 3 | /* Description: Truncates all version history */ 4 | /* that can bloat a database. Be very careful */ 5 | /* with this one, there is no coming back */ 6 | /* Intended Kentico Verison: 11.x */ 7 | /* Author: Brian McKeiver (mcbeev@gmail.com) */ 8 | /* Revision: 1.0 */ 9 | /* Take a backup first! Don't be THAT guy! */ 10 | 11 | UPDATE CMS_ObjectSettings 12 | SET ObjectCheckedOutVersionHistoryID = NULL 13 | WHERE ObjectCheckedOutVersionHistoryID IS NOT NULL 14 | 15 | GO 16 | 17 | DELETE FROM CMS_ObjectVersionHistory 18 | -------------------------------------------------------------------------------- /src/KX11/KenticoClearVersionHistoryAndAttachmentHistory-STAGING-SAFE.v11.sql: -------------------------------------------------------------------------------- 1 | /* KenticoClearVersionHistoryAndAttachmentHistory.v11.sql */ 2 | /* Goal: Clean up data from Pages Tree */ 3 | /* Description: Truncates version history except the most recent. or checked out */ 4 | /* This is safer than totally clearing as if you push a page that has workflow */ 5 | /* but the version history is gone, then the staging module will not push */ 6 | /* Child objects, thus you could destroy any child relationships. This prevents that. */ 7 | /* Be very careful with this one, there is no coming back */ 8 | /* Intended Kentico Verison: 11.x */ 9 | /* Author: Trevor Fayas (tfayas@gmail.com) */ 10 | /* Revision: 1.0 */ 11 | /* Take a backup first! Don't be THAT guy! */ 12 | 13 | -- Delets Version Attachment Binding which also deletes the attachment history 14 | delete from CMS_VersionAttachment where VersionHistoryID in ( 15 | select VH.VersionHistoryID from CMS_VersionHistory VH 16 | left join CMS_Document D on D.DocumentID = VH.DocumentID 17 | where 18 | -- Don't select the current or published version histories 19 | D.DocumentCheckedOutVersionHistoryID <> VH.VersionHistoryID and 20 | D.DocumentPublishedVersionHistoryID <> VH.VersionHistoryID 21 | ) 22 | 23 | -- Delete the Workflow History 24 | delete from CMS_WorkflowHistory where VersionHistoryID in ( 25 | select VH.VersionHistoryID from CMS_VersionHistory VH 26 | left join CMS_Document D on D.DocumentID = VH.DocumentID 27 | where 28 | -- Don't select the current or published version histories 29 | D.DocumentCheckedOutVersionHistoryID <> VH.VersionHistoryID and 30 | D.DocumentPublishedVersionHistoryID <> VH.VersionHistoryID 31 | ) 32 | 33 | -- Delete the version history 34 | delete from CMS_VersionHistory where VersionHistoryID in ( 35 | select VH.VersionHistoryID from CMS_VersionHistory VH 36 | left join CMS_Document D on D.DocumentID = VH.DocumentID 37 | where 38 | -- Don't select the current or published version histories 39 | D.DocumentCheckedOutVersionHistoryID <> VH.VersionHistoryID and 40 | D.DocumentPublishedVersionHistoryID <> VH.VersionHistoryID 41 | ) 42 | -------------------------------------------------------------------------------- /src/KX11/KenticoClearVersionHistoryAndAttachmentHistory.v11.sql: -------------------------------------------------------------------------------- 1 | /* KenticoClearVersionHistoryAndAttachmentHistory.v11.sql */ 2 | /* Goal: Clean up data from Pages Tree */ 3 | /* Description: Truncates all version history */ 4 | /* that can bloat a database. Be very careful */ 5 | /* with this one, there is no coming back */ 6 | /* Intended Kentico Verison: 11.x */ 7 | /* Author: Brian McKeiver (mcbeev@gmail.com) */ 8 | /* Revision: 1.0 */ 9 | /* Take a backup first! Don't be THAT guy! */ 10 | 11 | TRUNCATE TABLE CMS_WorkflowHistory 12 | GO 13 | 14 | UPDATE CMS_Document SET 15 | DocumentCheckedOutVersionHistoryID = NULL 16 | ,DocumentPublishedVersionHistoryID = NULL 17 | GO 18 | 19 | TRUNCATE TABLE CMS_VersionAttachment 20 | GO 21 | 22 | DELETE FROM CMS_VersionHistory 23 | GO 24 | 25 | DELETE FROM CMS_AttachmentHistory -------------------------------------------------------------------------------- /src/KX11/KenticoDeleteAnalyticsData-ByDays.v11.sql: -------------------------------------------------------------------------------- 1 | 2 | /* KenticoDeleteAnalyticsData-ByDays.v11.sql */ 3 | /* Goal: Clean up analytics data beyond a given # of days */ 4 | /* Description: Deletes individual Analytics Hits that are beyond the given */ 5 | /* number of days. This way you can delete data that is older than XXX days. */ 6 | /* This can take a long time to run and isn't recommended you run while the site is */ 7 | /* Being hit. On one site with over 50 million records beyond the date it took 40 minutes to run. */ 8 | /* Be very careful with this one, there is no coming back */ 9 | /* Intended Kentico Verison: 11.x */ 10 | /* Author: Trevor Fayas (tfayas@gmail.com) */ 11 | /* Revision: 1.0 */ 12 | /* Take a backup first! Don't be THAT guy! */ 13 | 14 | 15 | declare @DaysToKeep int = 548; /* MODIFY ME */ 16 | declare @CutOffDate datetime = null; 17 | 18 | -- Creates the cut off point 19 | set @CutOffDate = DATEADD(day, -1*@DaysToKeep, GETDATE()) 20 | 21 | 22 | -- Delete various Analytics data that have an end time that is earlier than the cut off date. 23 | -- DateDiff(day, '2020-01-15', '2020-01-01') would result in a negative number (Keep), 24 | -- where as DateDiff(day, '2019-12-30', '2020-01-01') would result in a negative number and should be deleted 25 | delete from [Analytics_YearHits] 26 | where DATEDIFF(day, HitsEndTime, @CutOffDate) > 0 27 | 28 | delete from [Analytics_MonthHits] 29 | where DATEDIFF(day, HitsEndTime, @CutOffDate) > 0 30 | 31 | delete from [Analytics_WeekHits] 32 | where DATEDIFF(day, HitsEndTime, @CutOffDate) > 0 33 | 34 | delete from [Analytics_DayHits] 35 | where DATEDIFF(day, HitsEndTime, @CutOffDate) > 0 36 | 37 | delete from [Analytics_HourHits] 38 | where DATEDIFF(day, HitsEndTime, @CutOffDate) > 0 39 | -------------------------------------------------------------------------------- /src/KX11/KenticoDeleteAnalyticsData.v11.sql: -------------------------------------------------------------------------------- 1 | /* KenticoDeleteAnalyticsData.v11.sql */ 2 | /* Goal: Clear out Analytics_* */ 3 | /* Description: Truncates all rows in all */ 4 | /* Analytics_* */ 5 | /* Intended Kentico Verison: 11.x */ 6 | /* Author: Brian McKeiver (mcbeev@gmail.com) */ 7 | /* Revision: 1.0 */ 8 | /* Take a backup first! Don't be THAT guy! */ 9 | 10 | TRUNCATE TABLE Analytics_DayHits 11 | GO 12 | 13 | TRUNCATE TABLE Analytics_ExitPages 14 | GO 15 | 16 | TRUNCATE TABLE Analytics_HourHits 17 | GO 18 | 19 | TRUNCATE TABLE Analytics_MonthHits 20 | GO 21 | 22 | TRUNCATE TABLE Analytics_WeekHits 23 | GO 24 | 25 | TRUNCATE TABLE Analytics_MonthHits 26 | GO 27 | 28 | TRUNCATE TABLE Analytics_YearHits 29 | GO 30 | 31 | DELETE FROM Analytics_Statistics 32 | 33 | -------------------------------------------------------------------------------- /src/KX11/KenticoDeleteCOMOrdersInBulk.v11.sql: -------------------------------------------------------------------------------- 1 | /* KenticoDeleteCOMOrdersinBulk.v11.sql */ 2 | /* Goal: Clear out COM_Order tables in bulk */ 3 | /* Description: Bulk delete E-commerce orders */ 4 | /* and all of the related FK data, EXCEPT */ 5 | /* for an internal domain where we want to */ 6 | /* keep our test orders from */ 7 | /* Intended Kentico Verison: 11.x */ 8 | /* Author: Brian McKeiver (mcbeev@gmail.com) */ 9 | /* Revision: 1.0 */ 10 | /* Comment: Removing 10k orders took ~ 25s */ 11 | /* Take a backup first! Don't be THAT guy! */ 12 | 13 | DECLARE @EmailDomainToKeep NVARCHAR(512) 14 | DECLARE @OrderBillingAddressID INT 15 | DECLARE @OrderShippingAddressID INT 16 | DECLARE @OrderAddressUsedCount INT 17 | DECLARE @OrderID INT 18 | DECLARE @CustomerID INT 19 | DECLARE @TotalOrders INT 20 | DECLARE @BatchSize INT 21 | DECLARE @KeepCustomersAlive INT -- yeah it's that serious ;) 22 | DECLARE @CustomersRemoved INT 23 | DECLARE @DEBUG INT 24 | 25 | --Email domain of customer email addresses where we want to keep emails from (our testing orders) 26 | -- Always leave our customers and orders from this domain no matter what 27 | SET @EmailDomainToKeep = '@domain.com' 28 | 29 | --How many to delete at a time, be careful! 30 | SET @BatchSize = 1000 31 | 32 | --For printing of messages 33 | SET @DEBUG = 1 34 | 35 | --Default is to remove all Orphan'd Customers(Customers with no orders left) 36 | --Change to a 1 to keep them around and ONLY remove Orders and OrderItems 37 | SET @KeepCustomersAlive = 0 38 | 39 | --Just a counter for debug reasons 40 | SET @CustomersRemoved = 0 41 | 42 | SET NOCOUNT ON 43 | 44 | --Figure out how many Orders we can find to remove that don't match our email domain to keep 45 | SELECT @TotalOrders=COUNT(OrderID) 46 | FROM COM_Order O 47 | INNER JOIN COM_Customer C ON 48 | O.OrderCustomerID = C.CustomerID 49 | WHERE C.CustomerEmail NOT LIKE '%'+ @EmailDomainToKeep +'%' 50 | 51 | PRINT 'Total Orders found: ' + CONVERT(nvarchar(50), @TotalOrders) + ' that do not match domain to keep: ' + @EmailDomainToKeep 52 | 53 | IF @DEBUG = 1 PRINT 'Attempting to Remove up to ' + CONVERT(nvarchar(50), @BatchSize) + ' orders.' 54 | 55 | SELECT TOP (@BatchSize) OrderID INTO #tmpOrderIDs 56 | FROM COM_Order O 57 | INNER JOIN COM_Customer C ON 58 | O.OrderCustomerID = C.CustomerID 59 | WHERE C.CustomerEmail NOT LIKE '%'+ @EmailDomainToKeep +'%' 60 | ORDER BY OrderCustomerID 61 | 62 | WHILE EXISTS(SELECT * FROM #tmpOrderIds) 63 | BEGIN 64 | 65 | SELECT TOP 1 @OrderID = OrderID FROM #tmpOrderIDs 66 | IF @DEBUG = 1 PRINT @OrderID 67 | 68 | --Remove OrderItemSKUFile from this Order's Order Items 69 | --SELECT * FROM COM_OrderItemSKUFile WHERE [OrderItemID] IN ( 70 | DELETE FROM COM_OrderItemSKUFile WHERE [OrderItemID] IN ( 71 | SELECT [OrderItemID] 72 | FROM COM_OrderItem 73 | WHERE [OrderItemOrderID] = @OrderID 74 | ) 75 | 76 | --Remove Order Items from this Order's Order Items 77 | DELETE FROM COM_OrderItem WHERE [OrderItemOrderID] = @OrderID 78 | --SELECT * FROM COM_OrderItem WHERE [OrderItemOrderID] = @OrderID 79 | 80 | --Remove from the Order from the User's Order Status 81 | DELETE FROM COM_OrderStatusUser WHERE [OrderID] = @OrderID 82 | --SELECT * FROM COM_OrderStatusUser WHERE [OrderID] = @OrderID 83 | 84 | --Figure out the two Addresses and CustomerID 85 | SELECT @OrderBillingAddressID = COALESCE(OrderBillingAddressID, -1) 86 | ,@OrderShippingAddressID = COALESCE(OrderShippingAddressID, -1) 87 | ,@CustomerID = OrderCustomerID 88 | FROM COM_Order 89 | WHERE [OrderID] = @OrderID 90 | 91 | --Remove the Order 92 | DELETE FROM COM_Order WHERE [OrderID] = @OrderID 93 | --SELECT * FROM COM_Order WHERE [OrderID] = @OrderID 94 | 95 | --See if Billing Address is used on any orders still 96 | SELECT @OrderAddressUsedCount = Count(OrderCompanyAddressID) FROM COM_Order WHERE [OrderCompanyAddressID] = @OrderBillingAddressID 97 | IF @OrderAddressUsedCount = 0 AND @OrderBillingAddressID > 0 98 | BEGIN 99 | --Remove the Billing Addresses as they are no longer tied to any orders 100 | DELETE FROM COM_OrderAddress WHERE [AddressID] = @OrderBillingAddressID 101 | IF @DEBUG = 1 PRINT 'Deleted Billing Address ' + CONVERT(nvarchar(50), @OrderBillingAddressID) 102 | END 103 | 104 | SET @OrderAddressUsedCount = -1 105 | 106 | --See if Shipping Address is used on any orders still 107 | SELECT @OrderAddressUsedCount = Count(OrderCompanyAddressID) FROM COM_Order WHERE [OrderCompanyAddressID] = @OrderShippingAddressID 108 | IF @OrderAddressUsedCount = 0 AND @OrderShippingAddressID > 0 109 | BEGIN 110 | --Remove the Shipping Addresses as they are no longer tied to any orders 111 | DELETE FROM COM_OrderAddress WHERE [AddressID] = @OrderShippingAddressID 112 | IF @DEBUG = 1 PRINT 'Deleted Shipping Address ' + CONVERT(nvarchar(50), @OrderShippingAddressID) 113 | END 114 | 115 | IF @KeepCustomersAlive = 0 116 | BEGIN 117 | IF @DEBUG = 1 PRINT 'Attempting to Remove CustomerID '+ CONVERT(nvarchar(50), @CustomerID) 118 | 119 | --We just removed the last order for this customer, now we can remove the customer 120 | SELECT @TotalOrders = Count(OrderID) FROM COM_Order WHERE [OrderCustomerID] = @CustomerID 121 | IF @TotalOrders = 0 122 | BEGIN 123 | --Have to clear out the Shopping Cart references first 124 | DELETE COM_ShoppingCartSKU 125 | FROM COM_ShoppingCartSKU S 126 | INNER JOIN COM_ShoppingCart C ON 127 | S.ShoppingCartID = C.ShoppingCartID 128 | INNER JOIN COM_Customer CO ON 129 | C.ShoppingCartCustomerID = CO.CustomerID 130 | WHERE CO.CustomerID = @CustomerID 131 | 132 | DELETE COM_ShoppingCartCouponCode 133 | FROM COM_ShoppingCartCouponCode S 134 | INNER JOIN COM_ShoppingCart C ON 135 | S.ShoppingCartID = C.ShoppingCartID 136 | INNER JOIN COM_Customer CO ON 137 | C.ShoppingCartCustomerID = CO.CustomerID 138 | WHERE CO.CustomerID = @CustomerID 139 | 140 | DELETE COM_ShoppingCart WHERE ShoppingCartCustomerID = @CustomerID 141 | 142 | --Then clear out the addresses for this Customer 143 | DELETE COM_Address WHERE AddressCustomerID = @CustomerID 144 | 145 | --Finally! can remove the Customer 146 | DELETE COM_Customer WHERE CustomerID = @CustomerID 147 | 148 | SET @CustomersRemoved = @CustomersRemoved + 1 149 | IF @DEBUG = 1 PRINT 'Customer removed' 150 | END 151 | ELSE 152 | BEGIN 153 | PRINT 'Skipping as Customer still has orders' 154 | END 155 | 156 | END 157 | 158 | IF @DEBUG = 1 PRINT 'Deleted order ' + CONVERT(nvarchar(100), @OrderID) 159 | 160 | --Remove item from temp table to process 161 | DELETE FROM #tmpOrderIDs WHERE OrderID = @OrderID 162 | END 163 | 164 | SET NOCOUNT OFF 165 | 166 | DROP TABLE #tmpOrderIDs 167 | 168 | SELECT @TotalOrders = COUNT(OrderID) FROM COM_Order 169 | 170 | PRINT 'Removed ' + CONVERT(nvarchar(50), @BatchSize) + ' orders' 171 | Print 'Removed ' + CONVERT(nvarchar(50), @CustomersRemoved) + ' customers' 172 | PRINT 'Succcess. Total Orders Remain: ' + CONVERT(nvarchar(50), @TotalOrders) 173 | -------------------------------------------------------------------------------- /src/KX11/KenticoDeleteStagingData.v11.sql: -------------------------------------------------------------------------------- 1 | /* KenticoDeleteStagingDAta.v11.sql */ 2 | /* Goal: Clean up data from Content Staging */ 3 | /* Description: Truncates all Staging tasks */ 4 | /* that can bloat a database. Be very careful */ 5 | /* with this one, there is no coming back */ 6 | /* Intended Kentico Verison: 11.x */ 7 | /* Author: Brian McKeiver (mcbeev@gmail.com) */ 8 | /* Revision: 1.0 */ 9 | /* Take a backup first! Don't be THAT guy! */ 10 | 11 | TRUNCATE TABLE Staging_Synchronization 12 | 13 | GO 14 | 15 | DELETE FROM Staging_Task 16 | -------------------------------------------------------------------------------- /src/KX11/KenticoDisableTasksForDevSpinup.v11.sql: -------------------------------------------------------------------------------- 1 | /* KenticoDisableTasksForDevSpinup.v11.sql */ 2 | /* Goal: Create a safe dev instance from prod */ 3 | /* Description: Disable all scheduled tasks, */ 4 | /* remove SMTP server settings to ensure no */ 5 | /* emails go out, disable emails, and queue. */ 6 | /* Run this after your restore the DB and */ 7 | /* before you fire up the application code */ 8 | /* Intended Kentico Verison: 11.x */ 9 | /* Author: Brian McKeiver (mcbeev@gmail.com) */ 10 | /* Revision: 1.0 */ 11 | /* Take a backup first! Don't be THAT guy! */ 12 | 13 | --Disable all Scheduled Tasks 14 | UPDATE CMS_ScheduledTask SET TaskEnabled = 0 15 | 16 | --Remove all SMTP Servers from Additional SMTP servers 17 | TRUNCATE TABLE CMS_SMTPServerSite 18 | 19 | --Update Settings app to blank out main SMTP Settings 20 | UPDATE CMS_SettingsKey SET KeyValue = '' WHERE KeyName = 'CMSSMTPServer' 21 | UPDATE CMS_SettingsKey SET KeyValue = '' WHERE KeyName = 'CMSSMTPServerPassword' 22 | UPDATE CMS_SettingsKey SET KeyValue = '' WHERE KeyName = 'CMSSMTPServerUser' 23 | 24 | --Update Settings app to disable email and email queue 25 | UPDATE CMS_SettingsKey SET KeyValue = 'False' WHERE KeyName = 'CMSEmailsEnabled' 26 | UPDATE CMS_SettingsKey SET KeyValue = 'False' WHERE KeyName = 'CMSEmailQueueEnabled' 27 | 28 | --Disable all Content Staing Servers 29 | UPDATE Staging_Server SET ServerEnabled = 0 30 | 31 | --Disable all Web Farm Servers 32 | UPDATE CMS_WebFarmServer SET ServerEnabled = 0 33 | 34 | --Disable all Marketing Automation Processes 35 | UPDATE CMS_Workflow SET WorkflowEnabled = 0 WHERE ([WorkflowType] = 3) 36 | -------------------------------------------------------------------------------- /src/KX12-to-13-Upgrade/PostUpgrade/Dynamic-Routing-Migration/Instructions.md: -------------------------------------------------------------------------------- 1 | # Dynamic Routing 2 | Please see instructions on the [Dynamic Routing](https://github.com/KenticoDevTrev/DynamicRouting) Github page for scripts and tools to help migrate Dynamic Routing URL Slugs and alternative Urls, and scripts on how to remove Dynamic Routing once fully upgraded. -------------------------------------------------------------------------------- /src/KX12-to-13-Upgrade/PostUpgrade/POST-0-Table-ColumnChecks.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------------------------------- 2 | -------- POST UPGRADE Kentico Xperience 12 to Kentico Xperience 13 ----------- 3 | -------- Table + Column Schema Check ------------ 4 | -- Instances of Kentico Xperience that started before KX 12 may have an old -- 5 | -- Tables, Views, Index/Constraints/Functions, etc. These should be updated,-- 6 | -- obsolete items removed, and items updated if they differ from a fresh -- 7 | -- Kentico Xperience 13 installation. -- 8 | -- -- 9 | -- INSTRUCTIONS: 10 | -- 1. Have a fresh Kentico Xperience 13 database for comparison -- 11 | -- 2. Find and replace FRESH_XPERIENCEDB with the fresh Kentico 13 database -- 12 | -- 3. Find and replace UPGRADED_XPERIENCEDB with the database you upgrade -- 13 | -- 4. Run the query -- 14 | -- 5. Any table columns that show mean that the Column def differs and you -- 15 | -- should update your upgraded database to match the fresh copy -- 16 | -- 6. Any tables that exist in one database vs the other should be either -- 17 | -- added or removed, or no action taken if it's a custom element -- 18 | -- -- 19 | -- ALWAYS Backup before running these. Don't be THAT Guy -- 20 | -- Author: Trevor Fayas, version 1.0.0 -- 21 | ------------------------------------------------------------------------------- 22 | 23 | DECLARE @TableName nvarchar(100); 24 | 25 | DECLARE CUR_TABLES CURSOR FAST_FORWARD FOR 26 | SELECT distinct TableName 27 | FROM ( 28 | SELECT TABLE_SCHEMA+'.'+TABLE_NAME as TableName FROM FRESH_XPERIENCEDB.INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE='BASE TABLE' 29 | UNION ALL 30 | SELECT TABLE_SCHEMA+'.'+TABLE_NAME as TableName FROM UPGRADED_XPERIENCEDB.INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE='BASE TABLE' 31 | ) a 32 | order by TableName 33 | 34 | OPEN CUR_TABLES 35 | FETCH NEXT FROM CUR_TABLES INTO @TableName 36 | 37 | WHILE @@FETCH_STATUS = 0 38 | BEGIN 39 | 40 | IF (EXISTS (SELECT * FROM FRESH_XPERIENCEDB.INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA+'.'+TABLE_NAME = @TableName) and EXISTS (SELECT * FROM UPGRADED_XPERIENCEDB.INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA+'.'+TABLE_NAME = @TableName)) 41 | BEGIN 42 | -- Exists in both, compare 43 | if(EXISTS( 44 | SELECT @TableName as [Table], name, system_type_id, user_type_id,max_length, precision,scale, is_nullable, is_identity FROM FRESH_XPERIENCEDB.sys.columns 45 | WHERE object_id = OBJECT_ID('FRESH_XPERIENCEDB.'+@TableName) 46 | EXCEPT 47 | SELECT @TableName as [Table], name, system_type_id, user_type_id,max_length, precision,scale, is_nullable, is_identity FROM UPGRADED_XPERIENCEDB.sys.columns 48 | WHERE object_id = OBJECT_ID('UPGRADED_XPERIENCEDB.'+@TableName) 49 | )) 50 | BEGIN 51 | -- Show differences 52 | SELECT @TableName as [Table], name, system_type_id, user_type_id,max_length, precision,scale, is_nullable, is_identity FROM FRESH_XPERIENCEDB.sys.columns 53 | WHERE object_id = OBJECT_ID('FRESH_XPERIENCEDB.'+@TableName) 54 | EXCEPT 55 | 56 | SELECT @TableName as [Table], name, system_type_id, user_type_id,max_length, precision,scale, is_nullable, is_identity FROM UPGRADED_XPERIENCEDB.sys.columns 57 | WHERE object_id = OBJECT_ID('UPGRADED_XPERIENCEDB.'+@TableName) 58 | end 59 | END else begin 60 | -- Show which database it doesn't exist in 61 | Select case when EXISTS(SELECT * FROM FRESH_XPERIENCEDB.INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE='BASE TABLE' and TABLE_SCHEMA+'.'+TABLE_NAME = @TableName) then 'FRESH_XPERIENCEDB' else 'UPGRADED_XPERIENCEDB' end + '.'+@TableName as [No Match Table] 62 | end 63 | 64 | FETCH NEXT FROM CUR_TABLES INTO @TableName 65 | END 66 | CLOSE CUR_TABLES 67 | DEALLOCATE CUR_TABLES 68 | GO 69 | 70 | 71 | -------------------------------------------------------------------------------- /src/KX12-to-13-Upgrade/PostUpgrade/POST-1-Constraint-Check.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------------------------------- 2 | -------- POST UPGRADE Kentico Xperience 12 to Kentico Xperience 13 ----------- 3 | -------- Constraints/Index Check ------------ 4 | -- Instances of Kentico Xperience that started before KX 12 may have an old -- 5 | -- Tables, Views, Index/Constraints/Functions, etc. These should be updated,-- 6 | -- obsolete items removed, and items updated if they differ from a fresh -- 7 | -- Kentico Xperience 13 installation. -- 8 | -- -- 9 | -- INSTRUCTIONS: 10 | -- 1. Have a fresh Kentico Xperience 13 database for comparison -- 11 | -- 2. Find and replace FRESH_XPERIENCEDB with the fresh Kentico 13 database -- 12 | -- 3. Find and replace UPGRADED_XPERIENCEDB with the database you upgrade -- 13 | -- 4. Run the query -- 14 | -- 5. Any Constraints/Indexes identified show a different value, for these..-- 15 | -- A. Take any constraint that is on the normal Kentico 13 database, -- 16 | -- right click and 'Script ___ as' -> Drop and Create -> To Clipboard -- 17 | -- B. Paste this into a new window, and run in the DB context of your -- 18 | -- Upgraded Database. Usually you just paste and execute the code below-- 19 | -- the "Using [FRESH_XPERIENCEDB] GO" -- 20 | -- -- 21 | -- 6. If the index doesn't exist in the Fresh Kentico Xperience 13 database,-- 22 | -- you can should be able to remove it from your upgraded instance. -- 23 | -- 7. Re-run till everything that should be resolved is resolved. -- 24 | -- -- 25 | -- ALWAYS Backup before running these. Don't be THAT Guy -- 26 | -- Author: Trevor Fayas, version 1.0.0 -- 27 | ------------------------------------------------------------------------------- 28 | 29 | 30 | -- Combined 31 | select distinct * from ( 32 | 33 | select * from ( 34 | 35 | select * from ( 36 | select table_view, 37 | object_type, 38 | constraint_type, 39 | constraint_name, 40 | details 41 | from ( 42 | select schema_name(t.schema_id) + '.' + t.[name] as table_view, 43 | case when t.[type] = 'U' then 'Table' 44 | when t.[type] = 'V' then 'View' 45 | end as [object_type], 46 | case when c.[type] = 'PK' then 'Primary key' 47 | when c.[type] = 'UQ' then 'Unique constraint' 48 | when i.[type] = 1 then 'Unique clustered index' 49 | when i.type = 2 then 'Unique index' 50 | end as constraint_type, 51 | isnull(c.[name], i.[name]) as constraint_name, 52 | substring(column_names, 1, len(column_names)-1) as [details] 53 | from FRESH_XPERIENCEDB.sys.objects t 54 | left outer join FRESH_XPERIENCEDB.sys.indexes i 55 | on t.object_id = i.object_id 56 | left outer join FRESH_XPERIENCEDB.sys.key_constraints c 57 | on i.object_id = c.parent_object_id 58 | and i.index_id = c.unique_index_id 59 | cross apply (select col.[name] + ', ' 60 | from FRESH_XPERIENCEDB.sys.index_columns ic 61 | inner join FRESH_XPERIENCEDB.sys.columns col 62 | on ic.object_id = col.object_id 63 | and ic.column_id = col.column_id 64 | where ic.object_id = t.object_id 65 | and ic.index_id = i.index_id 66 | order by col.column_id 67 | for xml path ('') ) D (column_names) 68 | where is_unique = 1 69 | and t.is_ms_shipped <> 1 70 | union all 71 | select schema_name(fk_tab.schema_id) + '.' + fk_tab.name as foreign_table, 72 | 'Table', 73 | 'Foreign key', 74 | fk.name as fk_constraint_name, 75 | schema_name(pk_tab.schema_id) + '.' + pk_tab.name 76 | from FRESH_XPERIENCEDB.sys.foreign_keys fk 77 | inner join FRESH_XPERIENCEDB.sys.tables fk_tab 78 | on fk_tab.object_id = fk.parent_object_id 79 | inner join FRESH_XPERIENCEDB.sys.tables pk_tab 80 | on pk_tab.object_id = fk.referenced_object_id 81 | inner join FRESH_XPERIENCEDB.sys.foreign_key_columns fk_cols 82 | on fk_cols.constraint_object_id = fk.object_id 83 | union all 84 | select schema_name(t.schema_id) + '.' + t.[name], 85 | 'Table', 86 | 'Check constraint', 87 | con.[name] as constraint_name, 88 | con.[definition] 89 | from FRESH_XPERIENCEDB.sys.check_constraints con 90 | left outer join FRESH_XPERIENCEDB.sys.objects t 91 | on con.parent_object_id = t.object_id 92 | left outer join FRESH_XPERIENCEDB.sys.all_columns col 93 | on con.parent_column_id = col.column_id 94 | and con.parent_object_id = col.object_id 95 | union all 96 | select schema_name(t.schema_id) + '.' + t.[name], 97 | 'Table', 98 | 'Default constraint', 99 | con.[name], 100 | col.[name] + ' = ' + con.[definition] 101 | from FRESH_XPERIENCEDB.sys.default_constraints con 102 | left outer join FRESH_XPERIENCEDB.sys.objects t 103 | on con.parent_object_id = t.object_id 104 | left outer join FRESH_XPERIENCEDB.sys.all_columns col 105 | on con.parent_column_id = col.column_id 106 | and con.parent_object_id = col.object_id) a 107 | 108 | ) orig 109 | EXCEPT 110 | select * from ( 111 | select table_view, 112 | object_type, 113 | constraint_type, 114 | constraint_name, 115 | details 116 | from ( 117 | select schema_name(t.schema_id) + '.' + t.[name] as table_view, 118 | case when t.[type] = 'U' then 'Table' 119 | when t.[type] = 'V' then 'View' 120 | end as [object_type], 121 | case when c.[type] = 'PK' then 'Primary key' 122 | when c.[type] = 'UQ' then 'Unique constraint' 123 | when i.[type] = 1 then 'Unique clustered index' 124 | when i.type = 2 then 'Unique index' 125 | end as constraint_type, 126 | isnull(c.[name], i.[name]) as constraint_name, 127 | substring(column_names, 1, len(column_names)-1) as [details] 128 | from UPGRADED_XPERIENCEDB.sys.objects t 129 | left outer join UPGRADED_XPERIENCEDB.sys.indexes i 130 | on t.object_id = i.object_id 131 | left outer join UPGRADED_XPERIENCEDB.sys.key_constraints c 132 | on i.object_id = c.parent_object_id 133 | and i.index_id = c.unique_index_id 134 | cross apply (select col.[name] + ', ' 135 | from UPGRADED_XPERIENCEDB.sys.index_columns ic 136 | inner join UPGRADED_XPERIENCEDB.sys.columns col 137 | on ic.object_id = col.object_id 138 | and ic.column_id = col.column_id 139 | where ic.object_id = t.object_id 140 | and ic.index_id = i.index_id 141 | order by col.column_id 142 | for xml path ('') ) D (column_names) 143 | where is_unique = 1 144 | and t.is_ms_shipped <> 1 145 | union all 146 | select schema_name(fk_tab.schema_id) + '.' + fk_tab.name as foreign_table, 147 | 'Table', 148 | 'Foreign key', 149 | fk.name as fk_constraint_name, 150 | schema_name(pk_tab.schema_id) + '.' + pk_tab.name 151 | from UPGRADED_XPERIENCEDB.sys.foreign_keys fk 152 | inner join UPGRADED_XPERIENCEDB.sys.tables fk_tab 153 | on fk_tab.object_id = fk.parent_object_id 154 | inner join UPGRADED_XPERIENCEDB.sys.tables pk_tab 155 | on pk_tab.object_id = fk.referenced_object_id 156 | inner join UPGRADED_XPERIENCEDB.sys.foreign_key_columns fk_cols 157 | on fk_cols.constraint_object_id = fk.object_id 158 | union all 159 | select schema_name(t.schema_id) + '.' + t.[name], 160 | 'Table', 161 | 'Check constraint', 162 | con.[name] as constraint_name, 163 | con.[definition] 164 | from UPGRADED_XPERIENCEDB.sys.check_constraints con 165 | left outer join UPGRADED_XPERIENCEDB.sys.objects t 166 | on con.parent_object_id = t.object_id 167 | left outer join UPGRADED_XPERIENCEDB.sys.all_columns col 168 | on con.parent_column_id = col.column_id 169 | and con.parent_object_id = col.object_id 170 | union all 171 | select schema_name(t.schema_id) + '.' + t.[name], 172 | 'Table', 173 | 'Default constraint', 174 | con.[name], 175 | col.[name] + ' = ' + con.[definition] 176 | from UPGRADED_XPERIENCEDB.sys.default_constraints con 177 | left outer join UPGRADED_XPERIENCEDB.sys.objects t 178 | on con.parent_object_id = t.object_id 179 | left outer join UPGRADED_XPERIENCEDB.sys.all_columns col 180 | on con.parent_column_id = col.column_id 181 | and con.parent_object_id = col.object_id) a 182 | ) other 183 | ) OrigToUpgraded 184 | 185 | UNION ALL 186 | 187 | select * from ( 188 | select * from ( 189 | select table_view, 190 | object_type, 191 | constraint_type, 192 | constraint_name, 193 | details 194 | from ( 195 | select schema_name(t.schema_id) + '.' + t.[name] as table_view, 196 | case when t.[type] = 'U' then 'Table' 197 | when t.[type] = 'V' then 'View' 198 | end as [object_type], 199 | case when c.[type] = 'PK' then 'Primary key' 200 | when c.[type] = 'UQ' then 'Unique constraint' 201 | when i.[type] = 1 then 'Unique clustered index' 202 | when i.type = 2 then 'Unique index' 203 | end as constraint_type, 204 | isnull(c.[name], i.[name]) as constraint_name, 205 | substring(column_names, 1, len(column_names)-1) as [details] 206 | from UPGRADED_XPERIENCEDB.sys.objects t 207 | left outer join UPGRADED_XPERIENCEDB.sys.indexes i 208 | on t.object_id = i.object_id 209 | left outer join UPGRADED_XPERIENCEDB.sys.key_constraints c 210 | on i.object_id = c.parent_object_id 211 | and i.index_id = c.unique_index_id 212 | cross apply (select col.[name] + ', ' 213 | from UPGRADED_XPERIENCEDB.sys.index_columns ic 214 | inner join UPGRADED_XPERIENCEDB.sys.columns col 215 | on ic.object_id = col.object_id 216 | and ic.column_id = col.column_id 217 | where ic.object_id = t.object_id 218 | and ic.index_id = i.index_id 219 | order by col.column_id 220 | for xml path ('') ) D (column_names) 221 | where is_unique = 1 222 | and t.is_ms_shipped <> 1 223 | union all 224 | select schema_name(fk_tab.schema_id) + '.' + fk_tab.name as foreign_table, 225 | 'Table', 226 | 'Foreign key', 227 | fk.name as fk_constraint_name, 228 | schema_name(pk_tab.schema_id) + '.' + pk_tab.name 229 | from UPGRADED_XPERIENCEDB.sys.foreign_keys fk 230 | inner join UPGRADED_XPERIENCEDB.sys.tables fk_tab 231 | on fk_tab.object_id = fk.parent_object_id 232 | inner join UPGRADED_XPERIENCEDB.sys.tables pk_tab 233 | on pk_tab.object_id = fk.referenced_object_id 234 | inner join UPGRADED_XPERIENCEDB.sys.foreign_key_columns fk_cols 235 | on fk_cols.constraint_object_id = fk.object_id 236 | union all 237 | select schema_name(t.schema_id) + '.' + t.[name], 238 | 'Table', 239 | 'Check constraint', 240 | con.[name] as constraint_name, 241 | con.[definition] 242 | from UPGRADED_XPERIENCEDB.sys.check_constraints con 243 | left outer join UPGRADED_XPERIENCEDB.sys.objects t 244 | on con.parent_object_id = t.object_id 245 | left outer join UPGRADED_XPERIENCEDB.sys.all_columns col 246 | on con.parent_column_id = col.column_id 247 | and con.parent_object_id = col.object_id 248 | union all 249 | select schema_name(t.schema_id) + '.' + t.[name], 250 | 'Table', 251 | 'Default constraint', 252 | con.[name], 253 | col.[name] + ' = ' + con.[definition] 254 | from UPGRADED_XPERIENCEDB.sys.default_constraints con 255 | left outer join UPGRADED_XPERIENCEDB.sys.objects t 256 | on con.parent_object_id = t.object_id 257 | left outer join UPGRADED_XPERIENCEDB.sys.all_columns col 258 | on con.parent_column_id = col.column_id 259 | and con.parent_object_id = col.object_id) a 260 | 261 | ) orig 262 | EXCEPT 263 | select * from ( 264 | select table_view, 265 | object_type, 266 | constraint_type, 267 | constraint_name, 268 | details 269 | from ( 270 | select schema_name(t.schema_id) + '.' + t.[name] as table_view, 271 | case when t.[type] = 'U' then 'Table' 272 | when t.[type] = 'V' then 'View' 273 | end as [object_type], 274 | case when c.[type] = 'PK' then 'Primary key' 275 | when c.[type] = 'UQ' then 'Unique constraint' 276 | when i.[type] = 1 then 'Unique clustered index' 277 | when i.type = 2 then 'Unique index' 278 | end as constraint_type, 279 | isnull(c.[name], i.[name]) as constraint_name, 280 | substring(column_names, 1, len(column_names)-1) as [details] 281 | from UPGRADED_XPERIENCEDB.sys.objects t 282 | left outer join UPGRADED_XPERIENCEDB.sys.indexes i 283 | on t.object_id = i.object_id 284 | left outer join UPGRADED_XPERIENCEDB.sys.key_constraints c 285 | on i.object_id = c.parent_object_id 286 | and i.index_id = c.unique_index_id 287 | cross apply (select col.[name] + ', ' 288 | from UPGRADED_XPERIENCEDB.sys.index_columns ic 289 | inner join UPGRADED_XPERIENCEDB.sys.columns col 290 | on ic.object_id = col.object_id 291 | and ic.column_id = col.column_id 292 | where ic.object_id = t.object_id 293 | and ic.index_id = i.index_id 294 | order by col.column_id 295 | for xml path ('') ) D (column_names) 296 | where is_unique = 1 297 | and t.is_ms_shipped <> 1 298 | union all 299 | select schema_name(fk_tab.schema_id) + '.' + fk_tab.name as foreign_table, 300 | 'Table', 301 | 'Foreign key', 302 | fk.name as fk_constraint_name, 303 | schema_name(pk_tab.schema_id) + '.' + pk_tab.name 304 | from UPGRADED_XPERIENCEDB.sys.foreign_keys fk 305 | inner join UPGRADED_XPERIENCEDB.sys.tables fk_tab 306 | on fk_tab.object_id = fk.parent_object_id 307 | inner join UPGRADED_XPERIENCEDB.sys.tables pk_tab 308 | on pk_tab.object_id = fk.referenced_object_id 309 | inner join UPGRADED_XPERIENCEDB.sys.foreign_key_columns fk_cols 310 | on fk_cols.constraint_object_id = fk.object_id 311 | union all 312 | select schema_name(t.schema_id) + '.' + t.[name], 313 | 'Table', 314 | 'Check constraint', 315 | con.[name] as constraint_name, 316 | con.[definition] 317 | from UPGRADED_XPERIENCEDB.sys.check_constraints con 318 | left outer join UPGRADED_XPERIENCEDB.sys.objects t 319 | on con.parent_object_id = t.object_id 320 | left outer join UPGRADED_XPERIENCEDB.sys.all_columns col 321 | on con.parent_column_id = col.column_id 322 | and con.parent_object_id = col.object_id 323 | union all 324 | select schema_name(t.schema_id) + '.' + t.[name], 325 | 'Table', 326 | 'Default constraint', 327 | con.[name], 328 | col.[name] + ' = ' + con.[definition] 329 | from UPGRADED_XPERIENCEDB.sys.default_constraints con 330 | left outer join UPGRADED_XPERIENCEDB.sys.objects t 331 | on con.parent_object_id = t.object_id 332 | left outer join UPGRADED_XPERIENCEDB.sys.all_columns col 333 | on con.parent_column_id = col.column_id 334 | and con.parent_object_id = col.object_id) a 335 | ) other 336 | ) UpgradedToOriginal 337 | ) Combined 338 | 339 | order by table_view, constraint_type, constraint_name -------------------------------------------------------------------------------- /src/KX12-to-13-Upgrade/PostUpgrade/POST-2-ViewChecks.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------------------------------- 2 | -------- POST UPGRADE Kentico Xperience 12 to Kentico Xperience 13 ----------- 3 | -------- View Check ------------ 4 | -- Instances of Kentico Xperience that started before KX 12 may have an old -- 5 | -- Tables, Views, Index/Constraints/Functions, etc. These should be updated,-- 6 | -- obsolete items removed, and items updated if they differ from a fresh -- 7 | -- Kentico Xperience 13 installation. -- 8 | -- -- 9 | -- INSTRUCTIONS: 10 | -- 1. Have a fresh Kentico Xperience 13 database for comparison -- 11 | -- 2. Find and replace FRESH_XPERIENCEDB with the fresh Kentico 13 database -- 12 | -- 3. Find and replace UPGRADED_XPERIENCEDB with the database you upgrade -- 13 | -- 4. Run the query -- 14 | -- 5. Remove any Views that are not custom and seem to be obsolete -- 15 | -- 6. Add any Views that are missing from the Upgraded that are present on -- 16 | -- fresh Kentico Xperience 13 database. You can Right-click on the view -- 17 | -- and "Script View As -> Create To -> Clipboard, then paste and run in -- 18 | -- the context of your Upgraded database -- 19 | -- -- 20 | -- ALWAYS Backup before running these. Don't be THAT Guy -- 21 | -- Author: Trevor Fayas, version 1.0.0 -- 22 | ------------------------------------------------------------------------------- 23 | 24 | -- Checks Views that are found in one but not the other 25 | 26 | SELECT 27 | TABLE_NAME as View_Name, 'Remove From UPGRADED_XPERIENCEDB' as Instructions 28 | FROM UPGRADED_XPERIENCEDB.INFORMATION_SCHEMA.VIEWS 29 | EXCEPT 30 | SELECT 31 | TABLE_NAME as View_Name, 'Remove From UPGRADED_XPERIENCEDB' as Instructions 32 | FROM FRESH_XPERIENCEDB.INFORMATION_SCHEMA.VIEWS 33 | 34 | SELECT 35 | TABLE_NAME as View_Name, 'Add To UPGRADED_XPERIENCEDB' as Instructions 36 | FROM FRESH_XPERIENCEDB.INFORMATION_SCHEMA.VIEWS 37 | EXCEPT 38 | SELECT 39 | TABLE_NAME as View_Name, 'Add To UPGRADED_XPERIENCEDB' as Instructions 40 | FROM UPGRADED_XPERIENCEDB.INFORMATION_SCHEMA.VIEWS 41 | 42 | -------------------------------------------------------------------------------- /src/KX12-to-13-Upgrade/PostUpgrade/POST-3-StoredProcFunctionsCheck.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------------------------------- 2 | -------- POST UPGRADE Kentico Xperience 12 to Kentico Xperience 13 ----------- 3 | -------- Function/Procedure Check ------------ 4 | -- Instances of Kentico Xperience that started before KX 12 may have an old -- 5 | -- Tables, Views, Index/Constraints/Functions, etc. These should be updated,-- 6 | -- obsolete items removed, and items updated if they differ from a fresh -- 7 | -- Kentico Xperience 13 installation. -- 8 | -- -- 9 | -- INSTRUCTIONS: 10 | -- 1. Have a fresh Kentico Xperience 13 database for comparison -- 11 | -- 2. Find and replace FRESH_XPERIENCEDB with the fresh Kentico 13 database -- 12 | -- 3. Find and replace UPGRADED_XPERIENCEDB with the database you upgrade -- 13 | -- 4. Run the queries -- 14 | -- 5. The First set show any Functions/Procs that need to be removed -- 15 | -- Or added to the Upgraded database. -- 16 | -- 6. The second query compares the CONTENT of matching Functions/Procs -- 17 | -- for these items... -- 18 | -- A. Find the corresponding element on the fresh Kentico Xperience 13 -- 19 | -- Database, then right click on it -> 'Script ___ as' -> Alter to ->-- 20 | -- Clipboard. 21 | -- B. Paste into a window, ensure the DB Context is the upgraded database-- 22 | -- C. Run the generated code on your upgraded db (everything below the -- 23 | -- 'Using [FRESH_XPERIENCEDB] GO' portion -- 24 | -- 7. Re-run the query to ensure fixed. -- 25 | -- -- 26 | -- NOTE: The Function/Proc match check does a loose string comparison, they -- 27 | -- may be functionality identical but slightly different in syntax. Plus -- 28 | -- the generated Alter statement may not match the original proc. If you -- 29 | -- can't get a function/proc to match even after updating it, you can run -- 30 | -- the Alter Function/Proc on the Fresh Kentico Xperience 13 databaes so -- 31 | -- it's text will match what you are updating on your upgraded one. -- 32 | -- -- 33 | -- ALWAYS Backup before running these. Don't be THAT Guy -- 34 | -- Author: Trevor Fayas, version 1.0.0 -- 35 | ------------------------------------------------------------------------------- 36 | 37 | -- Checks Views that are found in one but not the other 38 | -- Can remove un-needed procs/functions, and add missing ones 39 | SELECT 40 | ROUTINE_NAME, 'Remove From UPGRADED_XPERIENCEDB Custom' as Instructions 41 | FROM UPGRADED_XPERIENCEDB.INFORMATION_SCHEMA.ROUTINES 42 | EXCEPT 43 | SELECT 44 | ROUTINE_NAME, 'Remove From UPGRADED_XPERIENCEDB Custom' as Instructions 45 | FROM FRESH_XPERIENCEDB.INFORMATION_SCHEMA.ROUTINES 46 | 47 | SELECT 48 | ROUTINE_NAME, 'Add To UPGRADED_XPERIENCEDB' as Instructions 49 | FROM FRESH_XPERIENCEDB.INFORMATION_SCHEMA.ROUTINES 50 | EXCEPT 51 | SELECT 52 | ROUTINE_NAME, 'Add To UPGRADED_XPERIENCEDB' as Instructions 53 | FROM UPGRADED_XPERIENCEDB.INFORMATION_SCHEMA.ROUTINES 54 | 55 | 56 | -- Stored procs that differ in content 57 | select * from ( 58 | SELECT 59 | ROUTINE_NAME, LTRIM(RTRIM(Replace(Replace(Replace(REPLACE(ROUTINE_DEFINITION, '[dbo].',''),' ',' '),CHAR(13), ' '),char(10), ' '))) as ROUTINE_DEFINITION, 'Update' as Instructions 60 | FROM UPGRADED_XPERIENCEDB.INFORMATION_SCHEMA.ROUTINES where Routine_name in (Select Routine_name from FRESH_XPERIENCEDB.INFORMATION_SCHEMA.ROUTINES) 61 | EXCEPT 62 | SELECT 63 | ROUTINE_NAME, LTRIM(RTRIM(Replace(Replace(Replace(REPLACE(ROUTINE_DEFINITION, '[dbo].',''),' ',' '),CHAR(13), ' '),char(10), ' '))) as ROUTINE_DEFINITION, 'Update' as Instructions 64 | FROM FRESH_XPERIENCEDB.INFORMATION_SCHEMA.ROUTINES 65 | ) combined order by Routine_Name -------------------------------------------------------------------------------- /src/KX12-to-13-Upgrade/PreUpgrade/Check-And-Convert-PageTypes-Queries.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------------------------------------------------------------------------------------- 2 | ----------- Page Type Prep for KX12 to KX13 (Routing) (by Trevor Fayas - github.com/kenticodevtrev --------------------- 3 | -------------------------------------------------------------------------------------------------------------------------- 4 | 5 | -------------------------------------------------------------------------------------------------------------------------- 6 | -- When going from Kentico Xperience 12 to Kentico Xperience 13, Kentico automatically converts Page Types and 7 | -- enables certain features. In Kentico Xperience 12, URL routing was not available except through the Dynamic 8 | -- Routing module. In Kentico Xperience 13, Url Routing is available. 9 | -- 10 | -- During upgrade, Kentico looks through the Page Types and sees if the ClassUrlPattern is not null/empty in order 11 | -- to determine which classes should have the URL Feature enabled. With the Dynamic Routing module for KX12, if 12 | -- the ClassURLPattern was empty, it ASSUMED the pattern was {% NodeAliasPath %}, and used this in generating urls. 13 | -- 14 | -- Kentico Xperience 13 also handles URLs slightly differently, it does not include any Non-Url feature enabled 15 | -- Page types in the URL generations. So if you have a page with NodeAliasPath /Articles/2020/May/Hello, and the 16 | -- 2020 and May elements are folders (or any page type without a ClassURLPattern), KX 12 will make the url 17 | -- /Articles/Hello instead of it's original URL of /Articles/2020/May/Hello 18 | -- 19 | -- To Fix this, before your upgrade, you need to add the {% NodeAliasPath %} ClassUrlPattern to any class you want 20 | -- to have URLs, or any class that you want to be included in the url generation. Below are some scripts to help this. 21 | -------------------------------------------------------------------------------------------------------------------------- 22 | 23 | -------------------------------------------------------------------------------------------------------------------------- 24 | ---------------------------- ALWAYS BACK UP BEFORE RUNNING: Don't be that guy! ------------------------------------------- 25 | ---------------------- Also in Kentico do a System -> Clear Cache / Restart Application after----------------------------- 26 | -------------------------------------------------------------------------------------------------------------------------- 27 | 28 | -------------------------------------------------------------------------------------------------------------------------- 29 | -- This query shows all no-ClassUrlPattern Pages with children that do have a URL. 30 | -- During upgrade, these URLs will be 'broken' and no match the original urls. 31 | -- INSTRUCTIONS: Run this, and take all ClassNames (with NeedsContainerConversion = 0) to the next query. 32 | -- take all ClassNames (with NeedsContainerConversion = 1) and run the ConvertToCoupled-KX12.sql script with them 33 | -------------------------------------------------------------------------------------------------------------------------- 34 | select Case when ParentClass.ClassIsCoupledClass = 0 then 1 else 0 end as NeedsContainerConversion, * from View_CMS_Tree_Joined Parent 35 | left join CMS_Class ParentClass on ParentClass.ClassID = Parent.NodeClassID 36 | where ClassIsDocumentType = 1 and nullif(ClassURLPattern, '') is null and ParentClass.Classname <> 'CMS.Root' 37 | and exists ( 38 | select * from View_CMS_Tree_Joined Sub 39 | left join CMS_Class SubClass on SubClass.ClassID = Sub.NodeClassID 40 | where (SubClass.ClassIsDocumentType = 1 and nullif(SubClass.ClassURLPattern, '') is not null and SubClass.Classname <> 'CMS.Root') and Sub.NodeAliasPath like Parent.NodeAliasPath+'/%' and Sub.NodeSiteID = Parent.NodeSiteID 41 | ) order by Parent.ClassName, Parent.NodeSiteID, Parent.NodeAliasPath 42 | 43 | 44 | -------------------------------------------------------------------------------------------------------------------------- 45 | -- This query converts Portal Engine Page Types to Content Only Types 46 | -------------------------------------------------------------------------------------------------------------------------- 47 | update CMS_Class set ClassURLPattern = '{% NodeAliasPath %}', ClassIsContentOnly = 1, ClassUrlPattern = '{% NodeAliasPath %}' where ClassIsDocumentType = 1 and ClassIsCoupledClass = 1 and COALESCE(ClassIsContentOnly, 0) = 0 48 | and ClassName in ('my.class') 49 | 50 | -------------------------------------------------------------------------------------------------------------------------- 51 | -- This query simply adds the {% NodeAliasPath %} to the ClassURLPattern, take the classes from the previous query and plug them in here, assuming NeedsContainerConversion = 0 52 | -------------------------------------------------------------------------------------------------------------------------- 53 | update CMS_Class set ClassURLPattern = '{% NodeAliasPath %}' where ClassIsDocumentType = 1 and ClassIsCoupledClass = 1 and Nullif(ClassURLPattern, '') is null 54 | and ClassName in ('my.class') 55 | 56 | 57 | -------------------------------------------------------------------------------------------------------------------------- 58 | -- This query shows all remaining no-ClassUrlPattern Classes and if they have pages. 59 | -- If these are not also updated (with the previous update query), then they will have URL feature disabled upon upgrade, and cannot easily be re-enabled. 60 | -- INSTRUCTIONS: Run this, and ask yourself "Will there ever be any child pages in the future that will need this page type as part of the URL Structure?" 61 | -- If yes, then add the ClassURLPattern with the query above. 62 | -- If no, then leave it, and it will not have the URL Feature enabled. 63 | -------------------------------------------------------------------------------------------------------------------------- 64 | select case when exists (select 0 from View_CMS_Tree_Joined V where V.NodeClassID = ClassID) then 1 else 0 end as HasPages, * from CMS_CLass where ClassIsDocumentType = 1 and nullif(ClassURLPattern, '') is null and Classname <> 'CMS.Root' 65 | -------------------------------------------------------------------------------- /src/KX12-to-13-Upgrade/PreUpgrade/Convert-Container-PageTypes-To-CoupledWithUrl.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------------------------------------------------------------------------------------- 2 | ----------- Container to Coupled Page Type Converter for KX12 (by Trevor Fayas - github.com/kenticodevtrev ------------- 3 | -------------------------------------------------------------------------------------------------------------------------- 4 | 5 | -------------------------------------------------------------------------------------------------------------------------- 6 | -- KX13 does not have Containered Page Types, generally (they exist but you can't create them). 7 | -- Coupled with this, many Containered page types (such as folders) in KX12 still were used as part of the URL structure 8 | -- generation. Since during the KX12 to KX13 upgrade, any page types with an empty or null ClassURLPattern have the URL 9 | -- featured disabled and are not included thus in URL generation for any child elements, this can cause issues with old 10 | -- URLs no longer existing. An example is if you have a page with NodeAliasPath /Articles/2020/May/Hello, and the 11 | -- 2020 and May elements are folders (or any page type without a ClassURLPattern), KX 12 will make the url 12 | -- /Articles/Hello instead of it's original URL of /Articles/2020/May/Hello 13 | -- 14 | -- To Fix this, before your upgrade, you should convert Container Page Types to normal Content Only Coupled Page Types, 15 | -- and have the ClassURLPattern set to {% NodeAliasPath %}. This script does this for you, adding a "Name" Field and 16 | -- proper joining tables. 17 | -------------------------------------------------------------------------------------------------------------------------- 18 | 19 | -------------------------------------------------------------------------------------------------------------------------- 20 | ---------------------------- ALWAYS BACK UP BEFORE RUNNING: Don't be that guy! ------------------------------------------- 21 | ---------------------- Also in Kentico do a System -> Clear Cache / Restart Application after----------------------------- 22 | -------------------------------------------------------------------------------------------------------------------------- 23 | 24 | -- MODIFY THESE 3 ONLY 25 | -- Example for class Generic.Folder 26 | declare @Namespace nvarchar(100) = 'Generic' 27 | declare @Name nvarchar(100) = 'Folder' 28 | declare @EnsureUrlPattern bit = 1; -- Adds {% NodeAliasPath %} to the ClassURLPattern 29 | 30 | -- DO NOT MODIFY BELOW 31 | declare @ClassName nvarchar(200); 32 | declare @TableName nvarchar(200); 33 | declare @FormIDFieldGuid nvarchar(50); 34 | declare @FormNameFieldGuid nvarchar(50); 35 | declare @FormIDSearchFieldGuid nvarchar(50); 36 | declare @FormNameSearchFieldGuid nvarchar(50); 37 | set @ClassName = @Namespace+'.'+@Name 38 | set @TableName = @Namespace+'_'+@Name 39 | set @FormIDFieldGuid = LOWER(Convert(nvarchar(50), NewID())); 40 | set @FormNameFieldGuid = LOWER(Convert(nvarchar(50), NewID())); 41 | set @FormIDSearchFieldGuid = LOWER(Convert(nvarchar(50), NewID())); 42 | set @FormNameSearchFieldGuid = LOWER(Convert(nvarchar(50), NewID())); 43 | 44 | -- Update Class 45 | update CMS_Class set 46 | ClassIsDocumentType = 1, 47 | ClassIsCoupledClass = 1, 48 | ClassXmlSchema = ' 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 | ClassFormDefinition = '
'+@Name+'IDlabelcontrolNameFalseFalseFalseTextBoxControlFalseFalse
', 76 | ClassNodeNameSource = 'Name', 77 | ClassTableName = @TableName, 78 | ClassShowTemplateSelection = null, 79 | ClassIsMenuItemType = null, 80 | ClassSearchTitleColumn = 'DocumentName', 81 | ClassSearchContentColumn='DocumentContent', 82 | ClassSearchCreationDateColumn = 'DocumentCreatedWhen', 83 | ClassSearchSettings = '', 84 | ClassInheritsFromClassID = 0, 85 | ClassSearchEnabled = 1, 86 | ClassIsContentOnly = 1, 87 | ClassURLPattern = case when @EnsureUrlPattern = 1 then '{% NodeAliasPath %}' else ClassURLPattern end 88 | where ClassName = @ClassName 89 | 90 | -- Create table 91 | declare @CreateTable nvarchar(max); 92 | set @CreateTable = ' 93 | CREATE TABLE [dbo].['+@TableName+']( 94 | ['+@Name+'ID] [int] IDENTITY(1,1) NOT NULL, 95 | [Name] [nvarchar](200) NOT NULL, 96 | CONSTRAINT [PK_'+@TableName+'] PRIMARY KEY CLUSTERED 97 | ( 98 | ['+@Name+'ID] ASC 99 | )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] 100 | ) ON [PRIMARY] 101 | ALTER TABLE [dbo].['+@TableName+'] ADD CONSTRAINT [DEFAULT_'+@TableName+'_Name] DEFAULT (N'''') FOR [Name]' 102 | exec(@CreateTable); 103 | 104 | -- Populate joining table data, as well as generate the default url path entry based on nodealiaspath 105 | declare @BindingAndVersionSQL nvarchar(max); 106 | 107 | set @BindingAndVersionSQL = ' 108 | declare @ClassName nvarchar(200); 109 | declare @TableName nvarchar(200); 110 | declare @documentid int; 111 | declare @documentname nvarchar(200); 112 | declare @documentculture nvarchar(10); 113 | declare @NodeID int; 114 | declare @SiteID int; 115 | declare @newrowid int; 116 | set @ClassName = '''+@Namespace+'.'+@Name+''' 117 | set @TableName = '''+@Namespace+'_'+@Name+''' 118 | declare contenttable_cursor cursor for 119 | select * from ( 120 | select 121 | COALESCE(D.DocumentID, NoCultureD.DocumentID) as DocumentID, 122 | COALESCE(D.DocumentName, NoCultureD.DocumentName) as DocumentName, 123 | C.CultureCode, 124 | NodeID, 125 | NodeSiteID 126 | from CMS_Site S 127 | left join CMS_SiteCulture SC on SC.SiteID = S.SiteID 128 | left join CMS_Culture C on C.CultureID = SC.CultureID 129 | left join CMS_Tree on NodeSiteID = S.SiteID 130 | left join CMS_Class on ClassID = NodeClassID 131 | left outer join CMS_Document D on D.DocumentNodeID = NodeID and D.DocumentCulture = C.CultureCode 132 | left outer join CMS_Document NoCultureD on NoCultureD.DocumentNodeID = NodeID 133 | where ClassName = @ClassName 134 | ) cultureAcross 135 | group by DocumentID, DocumentName, CultureCode, NodeID, NodeSiteID 136 | order by DocumentID 137 | open contenttable_cursor 138 | fetch next from contenttable_cursor into @documentid, @documentname, @documentculture, @NodeID, @SiteID 139 | WHILE @@FETCH_STATUS = 0 BEGIN 140 | -- insert into binding table -- 141 | INSERT INTO [dbo].['+@TableName+'] ([Name]) VALUES (@documentname) 142 | 143 | -- Update document -- 144 | set @newrowid = SCOPE_IDENTITY(); 145 | update CMS_Document set DocumentForeignKeyValue = @newrowid where DocumentID = @documentid 146 | 147 | -- update also history -- 148 | update CMS_VersionHistory set NodeXML = replace(NodeXML, ''''+CONVERT(nvarchar(10), @documentid)+'''', ''''+CONVERT(nvarchar(10), @documentid)+''''+CONVERT(nvarchar(10), @newrowid)+'''') where DocumentID = @documentid 149 | 150 | FETCH NEXT FROM contenttable_cursor into @documentid, @documentname, @documentculture, @NodeID, @SiteID 151 | END 152 | Close contenttable_cursor 153 | DEALLOCATE contenttable_cursor' 154 | exec(@BindingAndVersionSQL) 155 | -------------------------------------------------------------------------------- /src/KX12-to-13-Upgrade/PreUpgrade/Convert-Site-To-Content-Only.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------------------------------------------------------------------------------------- 2 | ----------- Convert Site to MVC in Prep for KX12 to KX13 Upgrade (if site is portal engine) (by Trevor Fayas - github.com/kenticodevtrev) ------------- 3 | -------------------------------------------------------------------------------------------------------------------------- 4 | 5 | -------------------------------------------------------------------------------------------------------------------------- 6 | -- If your site is a Portal Engine site, you should convert it to a Content Only (MVC) Site prior to upgrading --- 7 | -------------------------------------------------------------------------------------------------------------------------- 8 | 9 | -------------------------------------------------------------------------------------------------------------------------- 10 | ---------------------------- ALWAYS BACK UP BEFORE RUNNING: Don't be that guy! ------------------------------------------- 11 | ---------------------- Also in Kentico do a System -> Clear Cache / Restart Application after----------------------------- 12 | -------------------------------------------------------------------------------------------------------------------------- 13 | 14 | update CMS_Site set SitePresentationURL = '', SiteIsContentOnly = 1 -------------------------------------------------------------------------------- /src/KX12-to-13-Upgrade/PreUpgrade/PREUPGRADE-0-Clear-UIElements.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------------------------------- 2 | -------- PRE UPGRADE Kentico Xperience 12 to Kentico Xperience 13 ------------ 3 | -------- UI Element Foreign Key Fix ------------ 4 | -- Instances of Kentico Xperience that started before KX 12 may have foreign -- 5 | -- key dependencies that will cause sql errors during upgrade. This script -- 6 | -- should be ran just prior to running the upgrade script to resolve UI -- 7 | -- foreign key dependencies. -- 8 | -- -- 9 | -- ALWAYS Backup before running these. Don't be THAT Guy -- 10 | -- Author: Trevor Fayas, version 1.0.0 -- 11 | ------------------------------------------------------------------------------- 12 | 13 | 14 | DECLARE @UIElements TABLE 15 | ( 16 | Identifier uniqueidentifier 17 | ); 18 | 19 | INSERT INTO @UIElements (Identifier) 20 | VALUES 21 | ('6b7eb9f5-9471-4f54-8944-f50ae15e03bb'), -- Remove Variants tab for content personalization (PLATFORM-15354) 22 | ('9e54b4da-4f2d-4491-a2d8-14cbb4e5fb24'), -- Remove Variants tab (PLATFORM-15312) 23 | ('1396d102-fcad-4b5d-bf80-fe945ff7b7c8'), -- Remove Persona tagging (CM-12683) 24 | ('b4004f19-d30f-422f-89a8-d60d5729f9ca'), -- Remove cms.file (PLATFORM-15236) 25 | ('d57a9cd2-5760-4573-99f1-04e8a8052b23'), 26 | ('773a0990-93a1-4375-907e-90e92a7c2a6b'), 27 | ('4b26978f-d069-4e20-a3e3-9c8ecaa67b55'), -- Remove sitemap support (PLATFORM-15183) 28 | ('facfa901-8cd4-41b0-854b-8beaf1b35a64'), 29 | ('912d9f65-02fd-42cb-a8b1-7f92b4e6dfe1'), -- Remove Template tab (PLATFORM-15135) 30 | ('21b7650b-f679-4227-a862-6b458acec104'), 31 | ('50f73376-9da6-465e-814b-2f701a2b6e36'), 32 | ('ad7d5ac2-c34d-4ec2-bc69-8ba584eb40ca'), 33 | ('afddc439-6216-4abb-bfd1-9300ba2ab5d8'), 34 | ('d46c2189-92f5-45b7-a34f-d21e8b342a67'), 35 | ('c7e0dd93-eac4-4567-8d1e-2dc845112c9f'), 36 | ('f4888178-fced-4854-81b6-e75ace98e80e'), 37 | ('fe219366-ce03-4d4f-a142-c036398a8ad3'), 38 | ('24ff71b5-2f83-4d93-acaa-d44ad230be41'), 39 | ('5bcc2097-7efa-49a7-9bb2-1c53b6bbbcc4'), 40 | ('555ea8b6-a655-4d82-89c8-168a63396d17'), 41 | ('b5a79666-a180-4be1-8dfb-fb297467edae'), -- Remove Online marketing section from General tab (PLATFORM-15096) 42 | ('8de24c03-0b37-40f1-9d16-417a97992d7a'), -- Remove Advanced section from General tab (PLATFORM-15095) 43 | ('e0892425-4454-4869-a31f-052af5b5fd5b'), -- Remove output cache fields (PLATFORM-15094) 44 | ('5ff31cb5-169b-424b-ad04-7acefea83542'), -- Remove custom etensions fields (PLATFORM-15091) 45 | ('ec3d79d1-6ba8-4ace-81eb-c73f846091b1'), -- Remove Analytics tab and sub-tabs (PLATFORM-15089) 46 | ('9692cedc-7b8c-4954-8bf4-aa136a038ae0'), 47 | ('73d4510b-7cee-4fc2-a49f-f840a56f0366'), 48 | ('f6413e96-fb74-40fa-bd7d-d987eee2ac3a'), 49 | ('993d8225-c9e9-48cd-ba70-d996d43155da'), 50 | ('ec7743a3-cee6-4873-bbe5-e9d4f130a081'), 51 | ('9b416d2a-72ff-437c-8e21-4c15cff785fb'), -- Remove Design tab and sub-tabs (PLATFORM-15058) 52 | ('2b4cef22-2b55-4915-bec2-c24ca254d61c'), 53 | ('5f30799d-4eb9-4002-b8e0-2387a526fa98'), 54 | ('f51d0a3f-852b-44ba-ba1e-74542b14f38a'), 55 | ('4958c021-feb5-4755-8d1a-9c67913ea453'), 56 | ('41f841fb-ae93-4d4d-a20a-05772efe2fa2'), 57 | ('550cf0ff-0b7f-42ab-989f-5373504a9890'), 58 | ('34172a4c-9104-4355-af2b-9da0c7c19386'), 59 | ('681fd60c-4998-41eb-8c10-91e03f0ce242'), 60 | ('68453d64-cbed-4917-9801-46e7f0d07676'), 61 | ('4c2fe72b-568a-4a4c-bb61-95dd3150aa39'), 62 | ('bc3aafb6-84dc-4ab0-87e7-36435ed42ad4'), 63 | ('aeb5cea7-da2c-4461-b594-bc52bc60b3f9'), 64 | ('49019e79-2e69-42fa-92be-0d744414ba6c'), 65 | ('beddc0cd-ceb3-4bd6-bb43-f9fb86bb38ac'), 66 | ('f854536c-307c-4b0e-ae64-52a48f31a3d8'), 67 | ('b30b9fc3-b193-4c6e-89ae-54c4f0fc7dcb'), 68 | ('8e525ca6-2573-46f6-84cd-59e0782bdbf2'), 69 | ('94fb8a06-d667-4741-a2ab-023ca918d3b6'), 70 | ('d7a93b63-c2e6-402a-9031-23475ded1f1c'), 71 | ('b9c0c264-2c24-4399-b5d4-5e9151ef7597'), 72 | ('c90240a4-5701-47f5-b29f-5ca84eb73eff'), 73 | ('7ee35791-5b19-456e-b5fb-f9c9a2908fd6'), 74 | ('40f0ce57-5ced-4394-ab20-f332655235de'), 75 | ('bc75c55b-4ba4-4a34-8a29-1a10facdfca0'), -- Remove DocumentUrlPath (PLATFORM-14965) 76 | ('ca81bd88-7e29-4e69-aa26-69b799573abe'), -- Master page tab (PLATFORM-14983) 77 | ('bf02c563-d83e-43ff-9991-7d87911b3056'), -- Page aliases (PLATFORM-15025) 78 | ('7aa16531-4f60-4aee-85df-89409c275610'), -- Page tab (PLATFORM-14690) 79 | ('ac5f7125-ec5e-4ed1-a400-de0676f46189'), -- Avatars (CM-12692) 80 | ('79deea0a-98a5-4df6-86b1-d5b7a859fc43'), -- Alternative URLs tab (PLATFORM-15503) 81 | ('f4a2df02-cf32-45c8-86e5-49432520f8ce'), -- Removed forms (PLATFORM-15603) 82 | ('46207f71-e9bf-4352-bc4d-1ce096411732'), 83 | ('0d7a48a0-1dae-493a-9d0b-f56a484f18de'), 84 | ('fcd48f9f-6283-4aaa-8fef-d5bf429d2142'), 85 | ('1cdc525c-aae2-4818-83d9-258c0d3b607c'), 86 | ('dcf0764b-72f2-4759-a143-1443f34bb337'), 87 | ('c7bb2f6f-7852-4487-ae52-f7b58ef72a6b'), 88 | ('51546812-c3da-40cb-8374-d779437c8ee6'), 89 | ('da79d75d-2bf7-427d-a6a4-011f6e194516'), 90 | ('01673678-c183-4785-acbf-cf4ef78e1dbd'), -- Remove Layout tab for page types (PLATFORM-15597) 91 | ('f837adb5-65d4-44f1-b2f1-92770d4d3162'), -- Remove Online Users from contact management (PLATFORM-15652) 92 | ('65b6dcb8-4e80-41ed-927e-6a747a9866db'), 93 | ('2ff9c4a7-19ef-4243-a10f-abc42a3dabbb'), 94 | ('70dc6207-8211-4c36-b58c-41958f833f5c'), -- Remove INLINE controls from WYSIWYG (CM-12914) 95 | ('a94ddf97-0b2c-4f74-9148-93c66c4e04a6'), 96 | ('60ccceff-1783-4239-bf23-6f03fe9eb61f'), 97 | ('fff72593-3e48-4979-bdf7-d4f7777fb038'), 98 | ('b4e584a0-fd5a-48f3-8d47-31c93f31618b'), 99 | ('b6a6e38d-465e-4719-a184-992c6e3f20d8'), 100 | ('2a65fe23-93d9-462f-ae1b-1b49133676b7'), -- Remove WebPart.Design element (PLATFORM-15649) 101 | ('5ed7c13f-1bc2-4504-a2fc-4c4be7513fd4'), 102 | ('251b022e-fc4e-4bb0-a6ec-60818fb7d2da'), 103 | ('e80b25ac-c61b-407b-9a43-b1a79a7055e4'), 104 | ('c4e5b361-f17d-4dca-934a-131b8d2bab86'), 105 | ('00cad23d-3b15-442a-9d0c-ac336478c97e'), -- Remove PageTemplateDeviceLayouts elements (PLATFORM-15987) 106 | ('ce87d8c9-3050-4b7a-b8ea-2f7821e7e6da'), 107 | ('c23d37da-c88a-463a-bac4-8401fcfc7883'), 108 | ('52b1b04e-0787-4932-a175-3daee7a7c42b'), 109 | ('714c267a-0ef3-4a08-9ac8-cd4dc412cfa0'), 110 | ('f1ce195f-6cea-4359-b19a-628d02d18e28'), 111 | ('99158ed5-3101-4e37-8121-309b1addc9cc'), -- Remove PageTemplate elements (PLATFORM-15986) 112 | ('34f28c89-2bd7-4fb7-b19f-ac8ec409e8f9'), 113 | ('d8570166-0f58-46a0-9659-423603ecb3b9'), 114 | ('b75fa37b-0611-4a7d-b0b5-8053a10629cf'), 115 | ('6e865cbc-fa69-4c3f-aef9-f8519d8b5688'), -- Remove On-line Marketing tabs in (Multi)Store configuration (PLATFORM-15983) 116 | ('8aa4c7a5-de53-4f0a-bb57-beed0c11fe80'), 117 | ('74615519-9fa1-492a-9e5d-e5adb12e1a8e'), -- Remove PageTemplates from Sites App (PLATFORM-16044) 118 | ('e587feb4-c356-4907-9efb-41d79ebd95b6'), 119 | ('c094677f-1a7b-4388-9f0f-dab906800e08'), -- Remove ABVariant (PLATFORM-15325) 120 | ('281a6791-6179-4a92-a86d-2fd410a19b45'), 121 | ('7dc5113e-991a-447c-8783-3d7e1472ebac'), 122 | ('f499da4c-efab-407c-ad89-b6ba99f71f8b'), 123 | ('ea681d2d-8f41-4b19-9dcf-bbccde6dc86b'), -- Remove SiteDomainAlias old UI (PLATFORM-16123) 124 | ('91a93923-df6b-4138-bc13-49ab28eec67d'), 125 | ('102f2747-b384-4776-80cc-655d2892d74e'), -- Removed aggregated views (PLATFORM-16201) 126 | ('ae98b2ff-26e0-4c6a-8e67-5ec8487ba3da'), 127 | ('2f7adb9f-bb4a-4f41-a53e-312a85b672bb'), 128 | ('d6a7f7f6-3009-478d-ae69-e9486bd51eb0'), -- Remove Report tab from Marketing Automation process (CM-13056) 129 | ('bd7fe72a-b2e2-4f3f-b880-1bb56582f524'), -- Remove Blogs (PLATFORM-16554) 130 | ('54eb846c-6048-4679-af6f-bfa1354c10e2'), 131 | ('5c77292d-92cc-4400-829d-66a158205110'), 132 | ('75691526-92b9-44ad-9788-c5885036e936'), 133 | ('c0536289-6aa5-4c86-8627-b91afc0ae7e5'), 134 | ('f9a3d08d-41bf-4922-b4a4-0b4110792785'), 135 | ('ab617598-21c4-4621-9fa1-bcdabf472579'), -- Remove abuse reports (PLATFORM-16566) 136 | ('60f7243c-64d1-4cce-8c93-ce4341a1b982'), -- Remove bad words (PLATFORM-16578) 137 | ('39e4ef11-67a9-4c95-b8d9-eca1888da932'), 138 | ('83811a53-08db-455c-ad99-7eaf3963fd37'), 139 | ('7c3ae191-3b32-41d8-bfce-7b28d3765b8e'), 140 | ('5bb05075-4f56-493a-8010-e41b25bc386f'), 141 | ('bb6226de-a2d9-4668-bd87-26e2eddb0cef'), -- Remove message boards (PLATFORM-16583) 142 | ('81baba69-3187-4efa-b72c-0193417b9d3f'), 143 | ('acf76596-b57c-4e1f-a77b-deea4130b2ec'), 144 | ('7e520518-c78f-4139-861d-3593a6b99784'), 145 | ('6d5fbafe-56b2-4e9a-ae8c-10da1be24b02'), 146 | ('a21b3f1e-99a7-467f-84df-917333330264'), 147 | ('f5512912-267c-4f53-8664-b387c32ccce4'), 148 | ('adbce010-8aa6-42d8-99e5-160032176cc6'), 149 | ('a81c0b81-28e9-4ed2-8f7e-ddbb7b3fd93e'), 150 | ('bc5e68ef-21fb-427c-8674-e6fe49bab83e'), 151 | ('e0460142-aa21-4c2c-81cf-178c42c4a86d'), 152 | ('216ce98b-8172-46f2-9c1e-b862a1414011'), 153 | ('2ac5ab8c-5fcf-4607-a9a8-c65b17bd4268'), 154 | ('768a3ad2-cf47-403b-83c3-1ee20fdf587e'), 155 | ('0ab9fbb4-8169-443b-8038-d13b5bdb2822'), 156 | ('fcab9deb-2b93-495f-8771-59393e29b008'), 157 | ('9957529b-0b4d-4ba6-9e12-a09a1ed1e65a'), 158 | ('12c1eb41-9b97-4477-9331-620a7fff2ecb'), 159 | ('4cd08eee-374b-4c82-84f8-8fd3dc091cb2'), -- Remove events (PLATFORM-16585) 160 | ('66068064-a270-4908-a20f-7c1013cb0301'), 161 | ('d826280d-23c7-4f2a-8efb-8f3b83df8393'), 162 | ('f0edfdd8-abfa-4c39-816a-5a40008bacf8'), 163 | ('c8d89c20-ab47-4e3a-a258-b08780446c3d'), -- Remove site offline mode, site bindings to polls, CSS stylesheets and web part containers (PLATFORM-15953) 164 | ('5c850d20-e93e-4edb-ace2-a9622f89241d'), 165 | ('caae294a-3431-4424-873a-7bb4fb03cdfc'), 166 | ('3b5e216e-2823-43bb-9c3d-c2a13a7c3723'), 167 | ('5d4aa6b6-93b8-4c7e-be30-8dfc74f5853e'), -- Web Analytics cleanup (PLATFORM-16206) 168 | ('96ae6b5b-a883-491b-a16d-2577e109dc23'), 169 | ('c9124c8d-d3e9-4f14-970d-57e6ad90d93a'), 170 | ('c86b3d64-87e5-4fbe-b498-8fd04c21549e'), 171 | ('5a32971f-607b-4bbe-b0ee-2e51e297e847'), 172 | ('f40d7df4-f29c-4554-8be7-0818a4429291'), 173 | ('2ef2d4a0-b2e3-4ede-bf72-c79e8be015e8'), 174 | ('7a09c17f-9960-403a-a4da-c77b1f3cf3a8'), 175 | ('ab290fd4-f707-45b8-944c-7e0f256f2be8'), -- Remove CSS app (PLATFORM-16591) 176 | ('2ca581af-450b-4617-88c1-6dc16c6c930e'), 177 | ('8494978e-4c28-40c8-9a6c-1f1c11cd9471'), 178 | ('7b0ce98c-4b39-4c16-9fb9-9d396fb9053e'), 179 | ('e7a7a816-117a-4cc9-b77f-6cf8c9b2aeaa'), 180 | ('756fe462-7e5e-498c-b0ce-6af7f7b41084'), 181 | ('c3a8ca8c-8a6a-42b4-b5a9-a8dafc93820b'), -- Remove CSS app (PLATFORM-15863) 182 | ('35f6778f-27ff-4420-94fa-12cfc0ea12e2'), 183 | ('8b198d0e-c384-4da7-97f2-4daa9edeae3b'), 184 | ('4440cc2c-e4ea-4955-be55-afb8c65f0bf7'), -- Remove MVT support (PLATFORM-15781) 185 | ('5824596e-f4a6-4d06-9621-3abe9181e9d7'), 186 | ('1b0c77d8-e09d-47ae-aeca-10cf43aa32d7'), 187 | ('a51d90f5-0ace-455a-a8cb-048454be53a3'), 188 | ('eaf9ce44-be29-409b-b2aa-e7b98b1c8ec2'), 189 | ('35f6778f-27ff-4420-94fa-12cfc0ea12e2'), 190 | ('8b198d0e-c384-4da7-97f2-4daa9edeae3b'), 191 | ('9ffd6c53-4c93-4137-b4eb-f948a48b683a'), -- Remove Badges (PLATFORM-16620) 192 | ('4931e81b-7b59-4340-a3d0-359fdbebb5de'), 193 | ('1a7b69ee-4f31-49d0-a7c4-a73d6e915df2'), 194 | ('141b0fa5-1ffe-4264-8a7b-f558e398d769'), -- Remove Forums (PLATFORM-16628) 195 | ('db250e18-f7c9-4eb9-8fd7-cacf80d8414b'), 196 | ('65bdec63-a802-4e38-97e3-3bb486eac2ba'), 197 | ('9921f272-9e5f-4467-8d42-76d0e1eabae0'), 198 | ('cf93caeb-3d56-46e3-ab74-c8168384ea73'), 199 | ('4f4a5812-7311-4e2c-aed4-c9ae84177efc'), 200 | ('767fef2f-5b2b-4e76-8e63-a6e8fdccb154'), 201 | ('df0a9a45-1983-4414-ade6-6c2ac398cd90'), 202 | ('ff02e464-a1d4-4f01-a0a7-ab6b2791b55c'), 203 | ('3bbd6057-122d-4fe2-81de-e0750ca9929c'), 204 | ('b1a545c3-b8d4-4112-b844-86f086194098'), 205 | ('df77b461-f1c5-45c0-8ac7-e0e80ca72eed'), 206 | ('cd638e2a-6ace-4e0c-85e0-14cc8a4ee1a5'), 207 | ('6e774946-e841-4e0e-9086-590efe2abfc3'), 208 | ('345f7685-1d34-4540-9d63-3bb6d7ee2bf9'), 209 | ('16774cdd-c2f7-4aaa-af9e-146ccb400f87'), 210 | ('634c7bc3-638b-4894-9d30-abb50d0261fb'), 211 | ('6acd5fa8-b28a-48e7-b439-b95eb5cda38e'), 212 | ('ae5f1d30-2fb0-40c7-9661-5b176dc3a536'), 213 | ('f245e6ec-d0f2-4e51-8546-a90d890eee63'), 214 | ('de463408-6153-447b-b7ac-785479d98087'), 215 | ('3ea3d682-147a-41ca-89db-419a029aa231'), 216 | ('9c372a01-21cc-418d-be86-8491ac3a2889'), 217 | ('79077afd-9f91-40fa-8926-7904f0e498f9'), 218 | ('5b75c243-132a-489e-a954-9725b9f1e87e'), 219 | ('265b0ee1-09c5-4c29-84d3-816f96960aae'), 220 | ('41ec9f5d-7569-454b-9af5-ddd7d39f4237'), -- Remove Navigation > Basic properties (PLATFORM-16611) 221 | ('48188299-29c3-45c8-92b6-d0a9bfc94418'), -- Web templates (PLATFORM-16588) 222 | ('324729ca-f2c7-4813-b7af-bc409a76e83b'), 223 | ('f95d0795-77d9-4047-ae4e-0b4616ff3b6d'), 224 | ('1c85c4b4-aeac-48bd-b02b-d25f67ff08a2'), -- Remove Polls (PLATFORM-15000) 225 | ('0b7c4fd1-b503-4ccb-a1d8-b50eeea704b6'), 226 | ('d37ed0ba-13e2-4907-8233-f3a1fcd06c6a'), 227 | ('52aa22a9-261e-4da1-af9b-3cae364773f4'), 228 | ('fbae4204-41f2-4a54-a13d-0dd705863209'), 229 | ('eb655ea1-9659-4120-a90e-6ef32deb0feb'), 230 | ('f758aa15-6888-4a7d-9dd8-10e306e9f7ad'), 231 | ('10209d17-6cd3-47d8-91b3-f718fa6c4000'), 232 | ('34dfa808-8f3e-47da-a465-b729ac959f69'), 233 | ('85372ca1-5f12-460c-9bd9-96b8f44029a5'), 234 | ('d37f6d82-131f-4195-b3ba-20c4bab56b71'), 235 | ('7a40f2e8-5f4e-45a7-af19-de2791c31206'), 236 | ('ef679cf1-ec6b-4590-bdcd-29bec5f07cf3'), 237 | ('3d90780f-f58b-4275-9ec6-165897095c82'), 238 | ('f04c3b54-ef8f-4acb-946a-3d1912228496'), -- Remove Banners (PLATFORM-15001) 239 | ('3bf5843e-ea8f-4d06-a0f5-fd9296ad798b'), 240 | ('ad39b67c-bb75-43f7-b7ea-3ad8850bb73b'), 241 | ('a0de1153-f314-4adc-b0ab-ba67ff1007e9'), 242 | ('edb610e5-fb99-457b-aefe-b7cd5787438e'), 243 | ('c48de8a2-2604-4d77-8e20-7eb2ce75733e'), 244 | ('d2456f97-8a79-48bb-9064-9fdacf97cfd6'), 245 | ('df982e11-1187-43ed-8c36-c2b15d5742fd'), 246 | ('d1341d4d-e94d-477b-a8c3-5af3cef52aff'), 247 | ('0712254E-BAB0-4CF1-9D2D-FEE5A1DB2BBB'), -- Remove Chat (PLATFORM-15006) 248 | ('D513547F-479E-407B-B063-8C7A966DF67D'), 249 | ('3B5A6663-B735-47A1-9AAB-F3EB00A99B96'), 250 | ('91628148-6EB3-4A7D-904A-1DA26928DD9F'), 251 | ('80014567-4648-485D-B937-410FEB3C51FE'), 252 | ('62B0ABE5-C34F-4770-83F2-BCED343A038F'), 253 | ('6E662840-BBAB-46A8-AAC7-90D9E1298EAC'), 254 | ('5302070C-C4CC-41CE-99B3-51473625289C'), 255 | ('743CF96B-D3DE-49F4-9049-5F4AD713EB91'), 256 | ('58FF5EAE-5DA0-4620-A73D-6D0D444E4F79'), 257 | ('639CB8EB-C204-4FFF-B823-0E8A74A71A67'), 258 | ('CB696D91-4951-4CF8-8A3F-D4F1AA853A3B'), 259 | ('FCD0F9BF-4A5D-4C2D-9061-14D79EA13B62'), 260 | ('F488432D-17FF-4030-BFBA-769B78DADBE9'), 261 | ('37C959EB-6673-4970-BC65-E76AF47943E6'), 262 | ('72b1e7b3-c6b9-4a18-afa1-3bb670fd61bb'), -- Pages app revision (PLATFORM-16610) 263 | ('1b319fa4-9f90-43f6-8f33-db3276b9ec99'), 264 | ('2C4BB770-3C04-48E4-BCA3-596A275BF63B'), -- Remove Conversions (PLATFORM-15002) 265 | ('7C283395-FEF5-4AD6-B47C-DDFE6E503E31'), 266 | ('2627E015-8B4D-43A7-8590-ECDD6AD43587'), 267 | ('ED89F99B-0BFE-4EFD-A754-2460718D69BE'), 268 | ('D12E3D37-51DF-4615-AC06-6C3DA2CFAFDC'), 269 | ('928C0610-9FC8-4944-B99F-E2E3AA0C6F10'), 270 | ('bf7d2d71-326e-421f-8848-8ddd0ff129b4'), -- Remove API Examples (PLATFORM-15011) 271 | ('a15b1a8d-e08e-4d5b-a2bf-d0f04a4c379a'), -- Remove Transformations tab of Custom tables (PLATFORM-16677) 272 | ('184cefeb-c0f5-4502-ad73-55a5cabaa449'), 273 | ('a99830e2-a544-4554-861d-977afc23ce3e'), 274 | ('eda8c0ac-28ac-4be5-8c63-8d615b8b175d'), -- Remove Transformations tab of Module classes (PLATFORM-16677) 275 | ('2f4eff8c-a436-4410-a4c2-8548ea2a23c4'), 276 | ('e9f38fe6-663a-49ea-a478-2b04534800ba'), 277 | ('b27ad799-90db-47ab-9e60-bb01b25a7075'), 278 | ('b2bb8374-ee51-467b-892e-f636a26c91bf'), -- Remove Transformations tab within hierarchical transformations' UI (PLATFORM-16679) 279 | ('f17d7ef4-b4ba-4ccb-85b0-eae2b74c2725'), -- Remove Theme tab of Transformations (PLATFORM-16677) 280 | ('5c373307-436f-4d66-b48e-f9d2a075e8d4'), -- Remove Javascript files (PLATFORM-15013) 281 | ('09af764d-69f8-4525-805a-0d0a3f34fab3'), -- Remove Notifications (PLATFORM-15014) 282 | ('c84a6d2c-cc0d-4c2d-b915-c987d6a08a5f'), 283 | ('022b51fd-3dba-4a8c-a87b-ddc7db99e6c0'), 284 | ('bae01dd5-56b8-43b7-ae54-f2c682a37b6c'), 285 | ('07f40f20-077c-4e6c-bd25-15a349fd41c9'), 286 | ('b823c66b-987d-4cdb-94c9-1d32b137f284'), 287 | ('3674f51d-bf34-4a3b-a462-fc30c0a87e34'), 288 | ('52454895-9104-4024-b63e-5426977e86fb'), 289 | ('8aec5087-e75b-463d-9f2c-ee39be04c84b'), 290 | ('618ecd01-9db1-4b50-9c67-3d2d2663851d'), 291 | ('e9a854e5-8dc5-48b4-8df4-125c4d9cdabc'), 292 | ('7c117298-87c4-4f9d-9c77-393e93c29f28'), 293 | ('DF536424-1C20-4A5F-A9EF-C632F06F6336'), -- Community groups 294 | ('91716FB1-BF2F-4CA6-92AB-F20BF348166D'), 295 | ('B189874F-0B3E-4680-A343-377409879A87'), 296 | ('9C73BFA6-BD54-4E7C-B2E3-1BB4455C5182'), 297 | ('1AA01C64-9413-46B3-8567-0DE33935FF7A'), 298 | ('D988CA19-D16F-44D9-B35C-2BF222ACC325'), 299 | ('B99C528E-D729-47F0-A3C4-839D0D910961'), 300 | ('320E0931-871A-4EAF-B369-CBA501ABB4A7'), 301 | ('1141571A-53F6-45A3-9E25-A841CB9E2251'), 302 | ('3F570F2C-E3DF-4608-ABF6-9A0A1E264113'), 303 | ('3463D612-60AC-4DB6-87E8-2A7731CE7511'), 304 | ('E03B1E03-9D27-48BF-9309-BE012A810EDA'), 305 | ('7CFC9C2F-9FAA-4BB8-94F1-FB890B31855C'), 306 | ('100B40E2-E0DE-4CDD-8D9A-B6AD3FACBB21'), 307 | ('9314ED30-17ED-4912-8DC2-D699D600EF21'), 308 | ('33CDA0EB-8013-4AED-888D-2DBC199C1906'), 309 | ('872a3765-bc7f-49e3-ad95-af19db23250e'), -- Device profiles UI (PLATFORM-15012) 310 | ('28483db1-36bd-43ff-9b35-3abc1ca1abfd'), 311 | ('157be65c-8dfa-4990-a2ca-38030992ca69'), 312 | ('f709e8b6-9b6d-4a60-b608-a49c3e44a9a5'), 313 | ('b8256c2a-09f7-47ff-a26f-1d7542003736'), 314 | ('b510ca56-2963-4e39-ba4f-5a13a7457e21'), 315 | ('f350ee3c-242e-4591-a3ea-12a3d13bf438'), -- On-site editing (PLATFORM-15199) 316 | ('931d00dd-440f-4c99-a7e5-678633e27f35'), 317 | ('02badb92-7a66-47a7-9c99-68e516d167ff'), 318 | ('9f9495ce-ca0e-4895-a49c-71a78692f966'), 319 | ('6c28e98f-c7b7-46dc-b9bb-8e5dd7a42d5a'), 320 | ('06328b52-19fb-4c32-8315-a9088468e29c'), 321 | ('e9c4120e-e506-4798-ac1d-a468854ceba3'), 322 | ('063236b5-6822-4f7a-a477-a80822debeb1'), 323 | ('585dba8e-25da-4345-a019-ed0bc096fae8'), 324 | ('7b169c33-ad0b-4813-af66-0f7ac3da6b83'), 325 | ('7a3216da-fa2e-4e26-9e32-ac5c67583d94'), 326 | ('158e437c-aaa3-460b-ad55-f053ed220d61'), 327 | ('651a9b2d-0b7a-4d9b-b87c-69259dc02397'), 328 | ('ea4e0eee-05e9-421a-8fcf-070a037356fb'), 329 | ('9bb73e7d-403b-45fd-9917-2d66117e4a4b'), 330 | ('fce2c698-6814-4eb5-9e3e-13b05438327d'), 331 | ('42ab6af5-8c68-4eae-990b-4cd26fd74ba8'), 332 | ('6a5e954e-b182-4d85-99c4-4d7006a9a3ed'), 333 | ('6abca888-a6e6-49d6-bb01-85aad206f860'), 334 | ('2ecd56ae-5dfe-4cb3-9da3-7e95455159f6'), 335 | ('14249b89-91e6-4463-bf03-c9e4e9feccbd'), -- Web part containers (PLATFORM-15015) 336 | ('13faa3ef-8abe-42bc-bae7-0a70251fa480'), 337 | ('4c4423bc-f860-455c-9889-00f7574ace88'), 338 | ('d56ccc0c-ce73-42cf-b294-5a51192dc76c'), 339 | ('185cc0c8-0c9d-41bb-ba41-c129ca3e9157'), 340 | ('2edbae72-14c0-42f7-a8b4-2bdd4eb67ad3'), 341 | ('dd3dbea4-07b5-4905-b090-f7eca0dacdd8'), -- Banned IPs (PLATFORM-14997) 342 | ('1c437eba-c14c-449c-9149-941a6d66f07a'), -- Settings revision remove Debug - Requests, Output, View State sections (PLATFORM-15331) 343 | ('0dd2e710-722b-4e99-a874-d2478343a208'), 344 | ('ea3ee278-5939-440c-a014-63c0c1028bee') 345 | ; 346 | 347 | DELETE FROM [CMS_RoleApplication] WHERE [ElementID] IN (SELECT [ElementID] FROM [CMS_UIElement] WHERE [ElementGUID] IN (SELECT Identifier FROM @UIElements)) 348 | DELETE FROM [CMS_RoleUIElement] WHERE [ElementID] IN (SELECT [ElementID] FROM [CMS_UIElement] WHERE [ElementGUID] IN (SELECT Identifier FROM @UIElements)) 349 | 350 | DECLARE @elementCursor CURSOR; 351 | SET @elementCursor = CURSOR FOR SELECT [Identifier] FROM @UIElements 352 | 353 | DECLARE @elementIdentifier uniqueidentifier; 354 | 355 | OPEN @elementCursor 356 | 357 | FETCH NEXT FROM @elementCursor INTO @elementIdentifier; 358 | WHILE @@FETCH_STATUS = 0 359 | BEGIN 360 | delete from CMS_RoleUIElement where CMS_RoleUIElement.ElementID in (Select lvl1.ElementID from CMS_UIElement lvl1 where lvl1.ElementGUID = @elementIdentifier) 361 | delete from CMS_RoleUIElement where CMS_RoleUIElement.ElementID in (Select lvl1.ElementID from CMS_UIElement lvl1 where lvl1.ElementParentID in (Select lvl2.ElementID from CMS_UIElement lvl2 where lvl2.ElementGUID = @elementIdentifier)) 362 | delete from CMS_RoleUIElement where CMS_RoleUIElement.ElementID in (Select lvl1.ElementID from CMS_UIElement lvl1 where lvl1.ElementParentID in (Select lvl2.ElementID from CMS_UIElement lvl2 where ElementParentID in (Select lvl3.ElementID from CMS_UIElement lvl3 where lvl3.ElementGUID = @elementIdentifier))) 363 | delete from CMS_RoleUIElement where CMS_RoleUIElement.ElementID in (Select lvl1.ElementID from CMS_UIElement lvl1 where lvl1.ElementParentID in (Select lvl2.ElementID from CMS_UIElement lvl2 where ElementParentID in (Select lvl3.ElementID from CMS_UIElement lvl3 where lvl3.ElementParentID in (Select lvl4.ElementID from CMS_UIElement lvl4 where lvl4.ElementGUID = @elementIdentifier)))) 364 | 365 | delete from CMS_UIElement where ElementParentID in (Select lvl1.ElementID from CMS_UIElement lvl1 where lvl1.ElementParentID in (Select lvl2.ElementID from CMS_UIElement lvl2 where ElementParentID in (Select lvl3.ElementID from CMS_UIElement lvl3 where lvl3.ElementGUID = @elementIdentifier))) 366 | delete from CMS_UIElement where ElementParentID in (Select lvl1.ElementID from CMS_UIElement lvl1 where lvl1.ElementParentID in (Select lvl2.ElementID from CMS_UIElement lvl2 where lvl2.ElementGUID = @elementIdentifier)) 367 | delete from CMS_UIElement where ElementParentID in (Select lvl1.ElementID from CMS_UIElement lvl1 where lvl1.ElementGUID = @elementIdentifier) 368 | delete from CMS_HelpTopic where HelpTopicUIElementID = (Select ElementID from CMS_UIElement where ElementGUID = @elementIdentifier) 369 | DELETE FROM [CMS_UIElement] WHERE [ElementGUID] = @elementIdentifier; 370 | 371 | FETCH NEXT FROM @elementCursor INTO @elementIdentifier; 372 | END 373 | -------------------------------------------------------------------------------- /src/KX12-to-13-Upgrade/PreUpgrade/PREUPGRADE-1-Clear-Resources.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------------------------------- 2 | -------- PRE UPGRADE Kentico Xperience 12 to Kentico Xperience 13 ------------ 3 | -------- Resource Foreign Key Fix ------------ 4 | -- Instances of Kentico Xperience that started before KX 12 may have foreign -- 5 | -- key dependencies that will cause sql errors during upgrade. This script -- 6 | -- should be ran just prior to running the upgrade script to resolve UI -- 7 | -- foreign key dependencies. -- 8 | -- -- 9 | -- ALWAYS Backup before running these. Don't be THAT Guy -- 10 | -- Author: Trevor Fayas, version 1.0.0 -- 11 | ------------------------------------------------------------------------------- 12 | 13 | DECLARE @Resources TABLE 14 | ( 15 | Identifier uniqueidentifier 16 | ); 17 | 18 | INSERT INTO @Resources (Identifier) 19 | VALUES 20 | ('913a8e05-207e-4116-83ed-1c35a499d654'), -- DancingGoat.Samples (PLATFORM-14731) 21 | ('65f419f4-00f1-4905-a344-fc5b94983097'), -- Community groups 22 | ('16ff5f79-b1c3-4142-bf28-e9fec523a10e'), -- Blogs (PLATFORM-16552) 23 | ('09642799-d831-4b69-a95d-28a9bdf496d9'), -- Bad words (PLATFORM-16577) 24 | ('69d64093-d17a-47e2-a08b-71800ac187b2'), -- Abuse reports (PLATFORM-16564) 25 | ('67c2d259-8f33-4c1f-b725-5eebcb332fcc'), -- Events booking (PLATFORM-16584) 26 | ('e2774a5e-1005-4911-877d-ad4af29a9976'), -- On-site editing (PLATFORM-15199) 27 | ('0011c831-2e12-45bf-87ed-6a17607659f8'), -- Message boards (PLATFORM-16582) 28 | ('0b5a5dd7-ce18-487a-96a3-a71434119b15'), -- Banned IPs (PLATFORM-14997) 29 | ('16e96e6c-f16f-49dc-a640-2357418668b8'), -- Forums (PLATFORM-16791) 30 | ('e673e837-394a-45f9-9591-9e75fe757763'), -- MVT (PLATFORM-16805) 31 | ('60976a10-849f-49fd-ae87-04688c7c1f80'), -- content personalization (PLATFORM-16807) 32 | ('944e7882-1698-4e87-9036-5d8cd4f98592'), -- Chat (PLATFORM-16661) 33 | ('c5f1114b-f87b-46bc-b169-7f8afaddc394'), -- Notifications (PLATFORM-16715) 34 | ('6a211ca9-a088-480d-b205-86af12b83935'), -- Device profiles (PLATFORM-16820) 35 | ('f1cc54a9-d5bb-4a69-bd8c-8918eb410656'), -- Community (PLATFORM-16710) 36 | ('69a6884d-789d-4732-bf7c-96da001050d8'), -- Banners (PLATFORM-16654) 37 | ('1235e27c-5b04-4024-9032-d10ea62cafbe') -- Strands recommender (PLATFORM-16705) 38 | ; 39 | DECLARE @elementCursor CURSOR; 40 | SET @elementCursor = CURSOR FOR SELECT [Identifier] FROM @Resources 41 | 42 | DECLARE @elementIdentifier uniqueidentifier; 43 | 44 | OPEN @elementCursor 45 | 46 | FETCH NEXT FROM @elementCursor INTO @elementIdentifier; 47 | WHILE @@FETCH_STATUS = 0 48 | BEGIN 49 | 50 | DELETE FROM [CMS_ResourceSite] WHERE [ResourceID] IN (Select R.ResourceID from CMS_Resource R where ResourceGUID =@elementIdentifier) 51 | delete from CMS_Widget where WidgetWebPartID in (Select WebPartID from CMS_Webpart where WebPartResourceID = (Select R.REsourceID from CMS_Resource R where ResourceGUID =@elementIdentifier)) 52 | delete from CMS_Webpart where WebPartResourceID = (Select R.REsourceID from CMS_Resource R where ResourceGUID =@elementIdentifier) 53 | delete from CMS_FormUserControl where UserControlResourceID in (Select R.REsourceID from CMS_Resource R where ResourceGUID =@elementIdentifier) 54 | delete from CMS_ScheduledTask where TaskResourceID in (Select R.REsourceID from CMS_Resource R where ResourceGUID =@elementIdentifier) 55 | delete from CMS_AlternativeForm where FormClassID in (select ClassID from CMS_Class where ClassResourceID in (Select R.REsourceID from CMS_Resource R where ResourceGUID =@elementIdentifier)) 56 | delete from CMS_Query where ClassID in (select ClassID from CMS_Class where ClassResourceID in (Select R.REsourceID from CMS_Resource R where ResourceGUID =@elementIdentifier)) 57 | delete from CMS_Class where ClassResourceID in (Select R.REsourceID from CMS_Resource R where ResourceGUID =@elementIdentifier) 58 | delete from CMS_RolePermission where PermissionID in (select P.PermissionID from CMS_Permission P where ResourceID in (Select R.REsourceID from CMS_Resource R where ResourceGUID =@elementIdentifier)) 59 | 60 | delete from CMS_Permission where ResourceID in (Select R.REsourceID from CMS_Resource R where ResourceGUID =@elementIdentifier) 61 | delete from CMS_SettingsKey where KeyCategoryID in (select C3.CategoryID from CMS_SettingsCategory C3 where C3.CategoryParentID in (select C2.CategoryID from CMS_SettingsCategory C2 where C2.CategoryParentID in (select C.CategoryID from CMS_SettingsCategory C where C.CategoryResourceID in (Select R.REsourceID from CMS_Resource R where ResourceGUID =@elementIdentifier)))) 62 | delete from CMS_SettingsKey where KeyCategoryID in (select CategoryID from CMS_SettingsCategory where CategoryParentID in (select C.CategoryID from CMS_SettingsCategory C where C.CategoryResourceID in (Select R.REsourceID from CMS_Resource R where ResourceGUID =@elementIdentifier))) 63 | delete from CMS_SettingsKey where KeyCategoryID in (select CategoryID from CMS_SettingsCategory where CategoryResourceID in (Select R.REsourceID from CMS_Resource R where ResourceGUID =@elementIdentifier)) 64 | delete from CMS_SettingsCategory where CategoryParentID in (select C2.CategoryID from CMS_SettingsCategory C2 where C2.CategoryParentID in (select C.CategoryID from CMS_SettingsCategory C where C.CategoryResourceID in (Select R.REsourceID from CMS_Resource R where ResourceGUID =@elementIdentifier))) 65 | delete from CMS_SettingsCategory where CategoryParentID in (select C.CategoryID from CMS_SettingsCategory C where C.CategoryResourceID in (Select R.REsourceID from CMS_Resource R where ResourceGUID =@elementIdentifier)) 66 | delete from CMS_SettingsCategory where CategoryResourceID in (Select R.REsourceID from CMS_Resource R where ResourceGUID =@elementIdentifier) 67 | 68 | DELETE FROM [CMS_Resource] WHERE [ResourceGUID] =@elementIdentifier 69 | 70 | 71 | FETCH NEXT FROM @elementCursor INTO @elementIdentifier; 72 | END 73 | 74 | -------------------------------------------------------------------------------- /src/KX12-to-13-Upgrade/PreUpgrade/PREUPGRADE-2-Remove-Templates.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------------------------------- 2 | -------- PRE UPGRADE Kentico Xperience 12 to Kentico Xperience 13 ------------ 3 | -------- Page Template Foreign Key Fix ------------ 4 | -- Instances of Kentico Xperience that started before KX 12 may have foreign -- 5 | -- key dependencies that will cause sql errors during upgrade. This script -- 6 | -- should be ran just prior to running the upgrade script to resolve UI -- 7 | -- foreign key dependencies. -- 8 | -- -- 9 | -- ALWAYS Backup before running these. Don't be THAT Guy -- 10 | -- Author: Trevor Fayas, version 1.0.0 -- 11 | ------------------------------------------------------------------------------- 12 | 13 | update CMS_Tree set NodeTemplateID = null 14 | update CMS_Document set DocumentPageTemplateID = null 15 | update CMS_Class set ClassDefaultPageTemplateID = null 16 | DECLARE @oldTemplates TABLE (PageTemplateID int) 17 | INSERT INTO @oldTemplates SELECT PageTemplateID FROM [CMS_PageTemplate] WHERE [PageTemplateType] IN ('portal', 'aspx', 'aspxportal') and PageTemplateID not in (select ElementPageTemplateID from CMS_UIElement where ElementPageTemplateID is not null) 18 | 19 | DELETE FROM [CMS_MetaFile] 20 | WHERE [MetaFileObjectType] = 'cms.pagetemplate' 21 | AND MetaFileObjectID IN (SELECT PageTemplateID FROM @oldTemplates) 22 | 23 | delete from CMS_TemplateDeviceLayout where PageTemplateID in ( 24 | select PT.PageTemplateID FROM [CMS_PageTemplate] PT 25 | WHERE PT.[PageTemplateID] IN (SELECT PageTemplateID FROM @oldTemplates) 26 | ) 27 | 28 | delete from CMS_PageTemplateSite where PageTemplateID in ( 29 | select PT.PageTemplateID FROM [CMS_PageTemplate] PT 30 | WHERE PT.[PageTemplateID] IN (SELECT PageTemplateID FROM @oldTemplates) 31 | ) 32 | 33 | delete from CMS_PageTemplateScope where PageTemplateScopeTemplateID in (SELECT PageTemplateID FROM @oldTemplates) 34 | 35 | DELETE FROM [CMS_PageTemplate] 36 | WHERE [PageTemplateID] IN (SELECT PageTemplateID FROM @oldTemplates) 37 | -------------------------------------------------------------------------------- /src/KX12-to-13-Upgrade/PreUpgrade/PREUPGRADE-3-DropStyleSheets.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------------------------------- 2 | -------- PRE UPGRADE Kentico Xperience 12 to Kentico Xperience 13 ------------ 3 | -------- CSS Stylesheet Foreign Key Fix ------------ 4 | -- Instances of Kentico Xperience that started before KX 12 may have foreign -- 5 | -- key dependencies that will cause sql errors during upgrade. This script -- 6 | -- should be ran just prior to running the upgrade script to resolve UI -- 7 | -- foreign key dependencies. -- 8 | -- -- 9 | -- ALWAYS Backup before running these. Don't be THAT Guy -- 10 | -- Author: Trevor Fayas, version 1.0.0 -- 11 | ------------------------------------------------------------------------------- 12 | 13 | alter table CMS_CssStyleSheetSite 14 | drop constraint FK_CMS_CssStylesheetSite_StylesheetID_CMS_CssStylesheet 15 | 16 | delete from CMS_CssStylesheetSite 17 | delete from [CMS_CssStylesheet] 18 | -------------------------------------------------------------------------------- /src/KX12-to-13-Upgrade/PreUpgrade/PREUPGRADE-4-CreateMissingConstraints.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------------------------------- 2 | -------- PRE UPGRADE Kentico Xperience 12 to Kentico Xperience 13 ------------ 3 | -------- Missing Key Constraint Fix ------------ 4 | -- Instances of Kentico Xperience that started before KX 12 may have foreign -- 5 | -- key dependencies that will cause sql errors during upgrade. This script -- 6 | -- should be ran just prior to running the upgrade script to resolve UI -- 7 | -- foreign key dependencies. -- 8 | -- -- 9 | -- ALWAYS Backup before running these. Don't be THAT Guy -- 10 | -- Author: Trevor Fayas, version 1.0.0 -- 11 | ------------------------------------------------------------------------------- 12 | 13 | ALTER TABLE [dbo].[CMS_VersionHistory] ADD CONSTRAINT [DEFAULT_CMS_VersionHistory_DocumentNamePath] DEFAULT (N'') FOR [DocumentNamePath] 14 | GO 15 | 16 | ALTER TABLE [dbo].[CMS_Document] ADD CONSTRAINT [DEFAULT_CMS_Document_DocumentInheritsStylesheet] DEFAULT ((1)) FOR [DocumentInheritsStylesheet] 17 | GO 18 | 19 | ALTER TABLE [dbo].[Analytics_Statistics] ADD CONSTRAINT [DEFAULT_Analytics_Statistics_StatisticsObjectCulture] DEFAULT (N'') FOR [StatisticsObjectCulture] 20 | GO 21 | 22 | ALTER TABLE [dbo].[Analytics_Statistics] ADD CONSTRAINT [DEFAULT_Analytics_Statistics_StatisticsObjectName] DEFAULT (N'') FOR [StatisticsObjectName] 23 | GO 24 | 25 | -------------------------------------------------------------------------------- /src/KX12-to-13-Upgrade/PreUpgrade/PREUPGRADE-5-SetCompatabilityLevel.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------------------------------- 2 | -------- PRE UPGRADE Kentico Xperience 12 to Kentico Xperience 13 ------------ 3 | -------- Database Compatability Level Fix ------------ 4 | -- Instances of Kentico Xperience that started before KX 12 may have an older-- 5 | -- database compatabilty level, which will caues an error when the upgrade -- 6 | -- tool attempts to use a function that only available at the 120 level. -- 7 | -- -- 8 | -- INSTRUCTIONS: Replace MY_XPERIENCE_DATABASE with your database name -- 9 | -- -- 10 | 11 | -- ALWAYS Backup before running these. Don't be THAT Guy -- 12 | -- Author: Trevor Fayas, version 1.0.0 -- 13 | ------------------------------------------------------------------------------- 14 | 15 | ALTER DATABASE MY_XPERIENCE_DATABASE SET COMPATIBILITY_LEVEL = 120; -------------------------------------------------------------------------------- /src/KX12-to-13-Upgrade/PreUpgrade/PREUPGRADE-6-RemovePMTables.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------------------------------- 2 | -------- PRE UPGRADE Kentico Xperience 12 to Kentico Xperience 13 ------------ 3 | -------- Database Compatability Level Fix ------------ 4 | -- Instances of Kentico Xperience that started before KX 12 may have an old -- 5 | -- PM Module that will cause a foreign key error on the OM_Group updates -- 6 | -- that occurr during the upgrade. This drops the tables as the feature is -- 7 | -- no longer supported. -- 8 | -- -- 9 | -- ALWAYS Backup before running these. Don't be THAT Guy -- 10 | -- Author: Trevor Fayas, version 1.0.0 -- 11 | ------------------------------------------------------------------------------- 12 | 13 | drop table PM_ProjectTask 14 | drop table PM_ProjectRolePermission 15 | drop table PM_Project 16 | drop table PM_ProjectStatus 17 | drop table PM_ProjectTaskPriority 18 | drop table PM_ProjectTaskStatus -------------------------------------------------------------------------------- /src/KX12/KenticoCheckUrlPatternsForUpgrade.v12.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------------------------------------------------------------------------------------- 2 | ----------- Page Type Prep for KX12 to KX13 (Routing) (by Trevor Fayas - github.com/kenticodevtrev --------------------- 3 | -------------------------------------------------------------------------------------------------------------------------- 4 | 5 | -------------------------------------------------------------------------------------------------------------------------- 6 | -- When going from Kentico Xperience 12 to Kentico Xperience 13, Kentico automatically converts Page Types and 7 | -- enables certain features. In Kentico Xperience 12, URL routing was not available except through the Dynamic 8 | -- Routing module. In Kentico Xperience 13, Url Routing is available. 9 | -- 10 | -- During upgrade, Kentico looks through the Page Types and sees if the ClassUrlPattern is not null/empty in order 11 | -- to determine which classes should have the URL Feature enabled. With the Dynamic Routing module for KX12, if 12 | -- the ClassURLPattern was empty, it ASSUMED the pattern was {% NodeAliasPath %}, and used this in generating urls. 13 | -- 14 | -- Kentico Xperience 13 also handles URLs slightly differently, it does not include any Non-Url feature enabled 15 | -- Page types in the URL generations. So if you have a page with NodeAliasPath /Articles/2020/May/Hello, and the 16 | -- 2020 and May elements are folders (or any page type without a ClassURLPattern), KX 12 will make the url 17 | -- /Articles/Hello instead of it's original URL of /Articles/2020/May/Hello 18 | -- 19 | -- To Fix this, before your upgrade, you need to add the {% NodeAliasPath %} ClassUrlPattern to any class you want 20 | -- to have URLs, or any class that you want to be included in the url generation. Below are some scripts to help this. 21 | -------------------------------------------------------------------------------------------------------------------------- 22 | 23 | -------------------------------------------------------------------------------------------------------------------------- 24 | ---------------------------- ALWAYS BACK UP BEFORE RUNNING: Don't be that guy! ------------------------------------------- 25 | ---------------------- Also in Kentico do a System -> Clear Cache / Restart Application after----------------------------- 26 | -------------------------------------------------------------------------------------------------------------------------- 27 | 28 | -------------------------------------------------------------------------------------------------------------------------- 29 | -- This query shows all no-ClassUrlPattern Pages with children that do have a URL. 30 | -- During upgrade, these URLs will be 'broken' and no match the original urls. 31 | -- INSTRUCTIONS: Run this, and take all ClassNames (with NeedsContainerConversion = 0) to the next query. 32 | -- take all ClassNames (with NeedsContainerConversion = 1) and run the ConvertToCoupled-KX12.sql script with them 33 | -------------------------------------------------------------------------------------------------------------------------- 34 | select Case when ParentClass.ClassIsCoupledClass = 0 then 1 else 0 end as NeedsContainerConversion, * from View_CMS_Tree_Joined Parent 35 | left join CMS_Class ParentClass on ParentClass.ClassID = Parent.NodeClassID 36 | where ClassIsDocumentType = 1 and nullif(ClassURLPattern, '') is null and ParentClass.Classname <> 'CMS.Root' 37 | and exists ( 38 | select * from View_CMS_Tree_Joined Sub 39 | left join CMS_Class SubClass on SubClass.ClassID = Sub.NodeClassID 40 | where (SubClass.ClassIsDocumentType = 1 and nullif(SubClass.ClassURLPattern, '') is not null and SubClass.Classname <> 'CMS.Root') and Sub.NodeAliasPath like Parent.NodeAliasPath+'/%' and Sub.NodeSiteID = Parent.NodeSiteID 41 | ) order by Parent.ClassName, Parent.NodeSiteID, Parent.NodeAliasPath 42 | 43 | 44 | -------------------------------------------------------------------------------------------------------------------------- 45 | -- This query simply adds the {% NodeAliasPath %} to the ClassURLPattern, take the classes from the previous query and plug them in here, assuming NeedsContainerConversion = 0 46 | -------------------------------------------------------------------------------------------------------------------------- 47 | update CMS_Class set ClassURLPattern = '{% NodeAliasPath %}' where ClassIsDocumentType = 1 and ClassIsCoupledClass = 1 and Coalesce(ClassURLPattern, '') is null 48 | and ClassName in ('my.class') 49 | 50 | 51 | -------------------------------------------------------------------------------------------------------------------------- 52 | -- This query shows all remaining no-ClassUrlPattern Classes and if they have pages. 53 | -- If these are not also updated (with the previous update query), then they will have URL feature disabled upon upgrade, and cannot easily be re-enabled. 54 | -- INSTRUCTIONS: Run this, and ask yourself "Will there ever be any child pages in the future that will need this page type as part of the URL Structure?" 55 | -- If yes, then add the ClassURLPattern with the query above. 56 | -- If no, then leave it, and it will not have the URL Feature enabled. 57 | -------------------------------------------------------------------------------------------------------------------------- 58 | select case when exists (select 0 from View_CMS_Tree_Joined V where V.NodeClassID = ClassID) then 1 else 0 end as HasPages, * from CMS_CLass where ClassIsDocumentType = 1 and nullif(ClassURLPattern, '') is null and Classname <> 'CMS.Root' 59 | -------------------------------------------------------------------------------- /src/KX12/KenticoCleanUpWebFarmServersAndTasks.v12.sql: -------------------------------------------------------------------------------- 1 | 2 | declare @server nvarchar(200), @serverid int 3 | set @server = '' 4 | 5 | select @serverid = serverid 6 | from cms_webfarmserver 7 | where servername = @server 8 | 9 | delete cms_webfarmserverlog 10 | where serverid = @serverid 11 | 12 | delete cms_webfarmservermonitoring 13 | where serverid = @serverid 14 | 15 | delete cms_webfarmservertask 16 | where serverid = @serverid 17 | 18 | delete cms_webfarmtask 19 | where TaskMachineName = @server 20 | 21 | delete cms_webfarmserver 22 | where serverid = @serverid 23 | -------------------------------------------------------------------------------- /src/KX12/KenticoClearObjectVersionHistory.v12.sql: -------------------------------------------------------------------------------- 1 | /* KenticoClearObjectVersionHistory.v12.sql */ 2 | /* Goal: Clean up data from objects */ 3 | /* Description: Truncates all version history */ 4 | /* that can bloat a database. Be very careful */ 5 | /* with this one, there is no coming back */ 6 | /* Intended Kentico Verison: 12.x */ 7 | /* Author: Brian McKeiver (mcbeev@gmail.com) */ 8 | /* Revision: 1.0 */ 9 | /* Take a backup first! Don't be THAT guy! */ 10 | 11 | UPDATE CMS_ObjectSettings 12 | SET ObjectCheckedOutVersionHistoryID = NULL 13 | WHERE ObjectCheckedOutVersionHistoryID IS NOT NULL 14 | 15 | GO 16 | 17 | DELETE FROM CMS_ObjectVersionHistory 18 | -------------------------------------------------------------------------------- /src/KX12/KenticoClearVersionHistoryAndAttachmentHistory-STAGING-SAFE.v11.sql: -------------------------------------------------------------------------------- 1 | /* KenticoClearVersionHistoryAndAttachmentHistory.v11.sql */ 2 | /* Goal: Clean up data from Pages Tree */ 3 | /* Description: Truncates version history except the most recent. or checked out */ 4 | /* This is safer than totally clearing as if you push a page that has workflow */ 5 | /* but the version history is gone, then the staging module will not push */ 6 | /* Child objects, thus you could destroy any child relationships. This prevents that. */ 7 | /* Be very careful with this one, there is no coming back */ 8 | /* Intended Kentico Verison: 11.x */ 9 | /* Author: Trevor Fayas (tfayas@gmail.com) */ 10 | /* Revision: 1.0 */ 11 | /* Take a backup first! Don't be THAT guy! */ 12 | 13 | -- Delets Version Attachment Binding which also deletes the attachment history 14 | delete from CMS_VersionAttachment where VersionHistoryID in ( 15 | select VH.VersionHistoryID from CMS_VersionHistory VH 16 | left join CMS_Document D on D.DocumentID = VH.DocumentID 17 | where 18 | -- Don't select the current or published version histories 19 | D.DocumentCheckedOutVersionHistoryID <> VH.VersionHistoryID and 20 | D.DocumentPublishedVersionHistoryID <> VH.VersionHistoryID 21 | ) 22 | 23 | -- Delete the Workflow History 24 | delete from CMS_WorkflowHistory where VersionHistoryID in ( 25 | select VH.VersionHistoryID from CMS_VersionHistory VH 26 | left join CMS_Document D on D.DocumentID = VH.DocumentID 27 | where 28 | -- Don't select the current or published version histories 29 | D.DocumentCheckedOutVersionHistoryID <> VH.VersionHistoryID and 30 | D.DocumentPublishedVersionHistoryID <> VH.VersionHistoryID 31 | ) 32 | 33 | -- Delete the version history 34 | delete from CMS_VersionHistory where VersionHistoryID in ( 35 | select VH.VersionHistoryID from CMS_VersionHistory VH 36 | left join CMS_Document D on D.DocumentID = VH.DocumentID 37 | where 38 | -- Don't select the current or published version histories 39 | D.DocumentCheckedOutVersionHistoryID <> VH.VersionHistoryID and 40 | D.DocumentPublishedVersionHistoryID <> VH.VersionHistoryID 41 | ) 42 | 43 | -- Remove attachment history for all versions no longer found 44 | delete from CMS_AttachmentHistory where AttachmentHistoryID not in ( 45 | select VAH.AttachmentHistoryID from CMS_VersionAttachment VAH 46 | ) 47 | -------------------------------------------------------------------------------- /src/KX12/KenticoClearVersionHistoryAndAttachmentHistory.v12.sql: -------------------------------------------------------------------------------- 1 | /* KenticoClearVersionHistoryAndAttachmentHistory.v12.sql */ 2 | /* Goal: Clean up data from Pages Tree */ 3 | /* Description: Truncates all version history */ 4 | /* that can bloat a database. Be very careful */ 5 | /* with this one, there is no coming back */ 6 | /* Intended Kentico Verison: 12.x */ 7 | /* Author: Brian McKeiver (mcbeev@gmail.com) */ 8 | /* Revision: 1.0 */ 9 | /* Take a backup first! Don't be THAT guy! */ 10 | 11 | TRUNCATE TABLE CMS_WorkflowHistory 12 | GO 13 | 14 | UPDATE CMS_Document SET 15 | DocumentCheckedOutVersionHistoryID = NULL 16 | ,DocumentPublishedVersionHistoryID = NULL 17 | GO 18 | 19 | TRUNCATE TABLE CMS_VersionAttachment 20 | GO 21 | 22 | DELETE FROM CMS_VersionHistory 23 | GO 24 | 25 | DELETE FROM CMS_AttachmentHistory -------------------------------------------------------------------------------- /src/KX12/KenticoConvertContainerPageTypeToCoupled.v12.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------------------------------------------------------------------------------------- 2 | ----------- Container to Coupled Page Type Converter for KX12 (by Trevor Fayas - github.com/kenticodevtrev ------------- 3 | -------------------------------------------------------------------------------------------------------------------------- 4 | 5 | -------------------------------------------------------------------------------------------------------------------------- 6 | -- KX13 does not have Containered Page Types, generally (they exist but you can't create them). 7 | -- Coupled with this, many Containered page types (such as folders) in KX12 still were used as part of the URL structure 8 | -- generation. Since during the KX12 to KX13 upgrade, any page types with an empty or null ClassURLPattern have the URL 9 | -- featured disabled and are not included thus in URL generation for any child elements, this can cause issues with old 10 | -- URLs no longer existing. An example is if you have a page with NodeAliasPath /Articles/2020/May/Hello, and the 11 | -- 2020 and May elements are folders (or any page type without a ClassURLPattern), KX 12 will make the url 12 | -- /Articles/Hello instead of it's original URL of /Articles/2020/May/Hello 13 | -- 14 | -- To Fix this, before your upgrade, you should convert Container Page Types to normal Content Only Coupled Page Types, 15 | -- and have the ClassURLPattern set to {% NodeAliasPath %}. This script does this for you, adding a "Name" Field and 16 | -- proper joining tables. 17 | -------------------------------------------------------------------------------------------------------------------------- 18 | 19 | -------------------------------------------------------------------------------------------------------------------------- 20 | ---------------------------- ALWAYS BACK UP BEFORE RUNNING: Don't be that guy! ------------------------------------------- 21 | ---------------------- Also in Kentico do a System -> Clear Cache / Restart Application after----------------------------- 22 | -------------------------------------------------------------------------------------------------------------------------- 23 | 24 | -- MODIFY THESE 3 ONLY 25 | -- Example for class Generic.Folder 26 | declare @Namespace nvarchar(100) = 'Generic' 27 | declare @Name nvarchar(100) = 'Folder' 28 | declare @EnsureUrlPattern bit = 1; -- Adds {% NodeAliasPath %} to the ClassURLPattern 29 | 30 | -- DO NOT MODIFY BELOW 31 | declare @ClassName nvarchar(200); 32 | declare @TableName nvarchar(200); 33 | declare @FormIDFieldGuid nvarchar(50); 34 | declare @FormNameFieldGuid nvarchar(50); 35 | declare @FormIDSearchFieldGuid nvarchar(50); 36 | declare @FormNameSearchFieldGuid nvarchar(50); 37 | set @ClassName = @Namespace+'.'+@Name 38 | set @TableName = @Namespace+'_'+@Name 39 | set @FormIDFieldGuid = LOWER(Convert(nvarchar(50), NewID())); 40 | set @FormNameFieldGuid = LOWER(Convert(nvarchar(50), NewID())); 41 | set @FormIDSearchFieldGuid = LOWER(Convert(nvarchar(50), NewID())); 42 | set @FormNameSearchFieldGuid = LOWER(Convert(nvarchar(50), NewID())); 43 | 44 | -- Update Class 45 | update CMS_Class set 46 | ClassIsDocumentType = 1, 47 | ClassIsCoupledClass = 1, 48 | ClassXmlSchema = ' 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 | ClassFormDefinition = '
'+@Name+'IDlabelcontrolNameFalseFalseFalseTextBoxControlFalseFalse
', 76 | ClassNodeNameSource = 'Name', 77 | ClassTableName = @TableName, 78 | ClassShowTemplateSelection = null, 79 | ClassIsMenuItemType = null, 80 | ClassSearchTitleColumn = 'DocumentName', 81 | ClassSearchContentColumn='DocumentContent', 82 | ClassSearchCreationDateColumn = 'DocumentCreatedWhen', 83 | ClassSearchSettings = '', 84 | ClassInheritsFromClassID = 0, 85 | ClassSearchEnabled = 1, 86 | ClassIsContentOnly = 1, 87 | ClassURLPattern = case when @EnsureUrlPattern = 1 then '{% NodeAliasPath %}' else ClassURLPattern end 88 | where ClassName = @ClassName 89 | 90 | -- Create table 91 | declare @CreateTable nvarchar(max); 92 | set @CreateTable = ' 93 | CREATE TABLE [dbo].['+@TableName+']( 94 | ['+@Name+'ID] [int] IDENTITY(1,1) NOT NULL, 95 | [Name] [nvarchar](200) NOT NULL, 96 | CONSTRAINT [PK_'+@TableName+'] PRIMARY KEY CLUSTERED 97 | ( 98 | ['+@Name+'ID] ASC 99 | )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] 100 | ) ON [PRIMARY] 101 | 102 | ALTER TABLE [dbo].['+@TableName+'] ADD CONSTRAINT [DEFAULT_'+@TableName+'_Name] DEFAULT (N'''') FOR [Name]' 103 | exec(@CreateTable); 104 | 105 | -- Populate joining table data, as well as generate the default url path entry based on nodealiaspath 106 | declare @BindingAndVersionSQL nvarchar(max); 107 | 108 | set @BindingAndVersionSQL = ' 109 | declare @ClassName nvarchar(200); 110 | declare @TableName nvarchar(200); 111 | declare @documentid int; 112 | declare @documentname nvarchar(200); 113 | declare @documentculture nvarchar(10); 114 | declare @NodeID int; 115 | declare @SiteID int; 116 | declare @newrowid int; 117 | 118 | set @ClassName = '''+@Namespace+'.'+@Name+''' 119 | set @TableName = '''+@Namespace+'_'+@Name+''' 120 | 121 | declare contenttable_cursor cursor for 122 | 123 | select * from ( 124 | select 125 | COALESCE(D.DocumentID, NoCultureD.DocumentID) as DocumentID, 126 | COALESCE(D.DocumentName, NoCultureD.DocumentName) as DocumentName, 127 | C.CultureCode, 128 | NodeID, 129 | NodeSiteID 130 | from CMS_Site S 131 | left join CMS_SiteCulture SC on SC.SiteID = S.SiteID 132 | left join CMS_Culture C on C.CultureID = SC.CultureID 133 | left join CMS_Tree on NodeSiteID = S.SiteID 134 | left join CMS_Class on ClassID = NodeClassID 135 | left outer join CMS_Document D on D.DocumentNodeID = NodeID and D.DocumentCulture = C.CultureCode 136 | left outer join CMS_Document NoCultureD on NoCultureD.DocumentNodeID = NodeID 137 | where ClassName = @ClassName 138 | ) cultureAcross 139 | group by DocumentID, DocumentName, CultureCode, NodeID, NodeSiteID 140 | order by DocumentID 141 | 142 | open contenttable_cursor 143 | fetch next from contenttable_cursor into @documentid, @documentname, @documentculture, @NodeID, @SiteID 144 | 145 | WHILE @@FETCH_STATUS = 0 BEGIN 146 | 147 | -- insert into binding table -- 148 | INSERT INTO [dbo].['+@TableName+'] ([Name]) VALUES (@documentname) 149 | 150 | -- Update document -- 151 | set @newrowid = SCOPE_IDENTITY(); 152 | update CMS_Document set DocumentForeignKeyValue = @newrowid where DocumentID = @documentid 153 | 154 | -- update also history -- 155 | update CMS_VersionHistory set NodeXML = replace(NodeXML, ''''+CONVERT(nvarchar(10), @documentid)+'''', ''''+CONVERT(nvarchar(10), @documentid)+''''+CONVERT(nvarchar(10), @newrowid)+'''') where DocumentID = @documentid 156 | 157 | FETCH NEXT FROM contenttable_cursor into @documentid, @documentname, @documentculture, @NodeID, @SiteID 158 | END 159 | Close contenttable_cursor 160 | DEALLOCATE contenttable_cursor' 161 | exec(@BindingAndVersionSQL) -------------------------------------------------------------------------------- /src/KX12/KenticoDeleteAnalyticsData-ByDays.v12.sql: -------------------------------------------------------------------------------- 1 | 2 | /* KenticoDeleteAnalyticsData-ByDays.v12.sql */ 3 | /* Goal: Clean up analytics data beyond a given # of days */ 4 | /* Description: Deletes individual Analytics Hits that are beyond the given */ 5 | /* number of days. This way you can delete data that is older than XXX days. */ 6 | /* This can take a long time to run and isn't recommended you run while the site is */ 7 | /* Being hit. On one site with over 50 million records beyond the date it took 40 minutes to run. */ 8 | /* Be very careful with this one, there is no coming back */ 9 | /* Intended Kentico Verison: 11.x */ 10 | /* Author: Trevor Fayas (tfayas@gmail.com) */ 11 | /* Revision: 1.0 */ 12 | /* Take a backup first! Don't be THAT guy! */ 13 | 14 | 15 | declare @DaysToKeep int = 548; /* MODIFY ME */ 16 | declare @CutOffDate datetime = null; 17 | 18 | -- Creates the cut off point 19 | set @CutOffDate = DATEADD(day, -1*@DaysToKeep, GETDATE()) 20 | 21 | 22 | -- Delete various Analytics data that have an end time that is earlier than the cut off date. 23 | -- DateDiff(day, '2020-01-15', '2020-01-01') would result in a negative number (Keep), 24 | -- where as DateDiff(day, '2019-12-30', '2020-01-01') would result in a negative number and should be deleted 25 | delete from [Analytics_YearHits] 26 | where DATEDIFF(day, HitsEndTime, @CutOffDate) > 0 27 | 28 | delete from [Analytics_MonthHits] 29 | where DATEDIFF(day, HitsEndTime, @CutOffDate) > 0 30 | 31 | delete from [Analytics_WeekHits] 32 | where DATEDIFF(day, HitsEndTime, @CutOffDate) > 0 33 | 34 | delete from [Analytics_DayHits] 35 | where DATEDIFF(day, HitsEndTime, @CutOffDate) > 0 36 | 37 | delete from [Analytics_HourHits] 38 | where DATEDIFF(day, HitsEndTime, @CutOffDate) > 0 39 | -------------------------------------------------------------------------------- /src/KX12/KenticoDeleteAnalyticsData.v12.sql: -------------------------------------------------------------------------------- 1 | /* KenticoDeleteAnalyticsData.v12.sql */ 2 | /* Goal: Clear out Analytics_* */ 3 | /* Description: Truncates all rows in all */ 4 | /* Analytics_* */ 5 | /* Intended Kentico Verison: 12.x */ 6 | /* Author: Brian McKeiver (mcbeev@gmail.com) */ 7 | /* Revision: 1.0 */ 8 | /* Take a backup first! Don't be THAT guy! */ 9 | 10 | TRUNCATE TABLE Analytics_DayHits 11 | GO 12 | 13 | TRUNCATE TABLE Analytics_ExitPages 14 | GO 15 | 16 | TRUNCATE TABLE Analytics_HourHits 17 | GO 18 | 19 | TRUNCATE TABLE Analytics_MonthHits 20 | GO 21 | 22 | TRUNCATE TABLE Analytics_WeekHits 23 | GO 24 | 25 | TRUNCATE TABLE Analytics_MonthHits 26 | GO 27 | 28 | TRUNCATE TABLE Analytics_YearHits 29 | GO 30 | 31 | DELETE FROM Analytics_Statistics 32 | 33 | -------------------------------------------------------------------------------- /src/KX12/KenticoDeleteCOMOrdersInBulk.v12.sql: -------------------------------------------------------------------------------- 1 | /* KenticoDeleteCOMOrdersinBulk.v12.sql */ 2 | /* Goal: Clear out COM_Order tables in bulk */ 3 | /* Description: Bulk delete E-commerce orders */ 4 | /* and all of the related FK data, EXCEPT */ 5 | /* for an internal domain where we want to */ 6 | /* keep our test orders from */ 7 | /* Intended Kentico Verison: 12.x */ 8 | /* Author: Brian McKeiver (mcbeev@gmail.com) */ 9 | /* Revision: 1.0 */ 10 | /* Comment: Removing 10k orders took ~ 25s */ 11 | /* Take a backup first! Don't be THAT guy! */ 12 | 13 | DECLARE @EmailDomainToKeep NVARCHAR(512) 14 | DECLARE @OrderID INT 15 | DECLARE @CustomerID INT 16 | DECLARE @TotalOrders INT 17 | DECLARE @BatchSize INT 18 | DECLARE @KeepCustomersAlive INT -- yeah it's that serious ;) 19 | DECLARE @CustomersRemoved INT 20 | DECLARE @DEBUG INT 21 | 22 | --Email domain of customer email addresses where we want to keep emails from (our testing orders) 23 | -- Always leave our customers and orders from this domain no matter what 24 | SET @EmailDomainToKeep = '@domain.com' 25 | 26 | --How many to delete at a time, be careful! 27 | SET @BatchSize = 1000 28 | 29 | --For printing of messages 30 | SET @DEBUG = 1 31 | 32 | --Default is to remove all Orphan'd Customers(Customers with no orders left) 33 | --Change to a 1 to keep them around and ONLY remove Orders and OrderItems 34 | SET @KeepCustomersAlive = 0 35 | 36 | --Just a counter for debug reasons 37 | SET @CustomersRemoved = 0 38 | 39 | SET NOCOUNT ON 40 | 41 | --Figure out how many Orders we can find to remove that don't match our email domain to keep 42 | SELECT @TotalOrders=COUNT(OrderID) 43 | FROM COM_Order O 44 | INNER JOIN COM_Customer C ON 45 | O.OrderCustomerID = C.CustomerID 46 | WHERE C.CustomerEmail NOT LIKE '%'+ @EmailDomainToKeep +'%' 47 | 48 | PRINT 'Total Orders found: ' + CONVERT(nvarchar(50), @TotalOrders) + ' that do not match domain to keep: ' + @EmailDomainToKeep 49 | 50 | IF @DEBUG = 1 PRINT 'Attempting to Remove up to ' + CONVERT(nvarchar(50), @BatchSize) + ' orders.' 51 | 52 | SELECT TOP (@BatchSize) OrderID INTO #tmpOrderIDs 53 | FROM COM_Order O 54 | INNER JOIN COM_Customer C ON 55 | O.OrderCustomerID = C.CustomerID 56 | WHERE C.CustomerEmail NOT LIKE '%'+ @EmailDomainToKeep +'%' 57 | ORDER BY OrderCustomerID 58 | 59 | WHILE EXISTS(SELECT * FROM #tmpOrderIds) 60 | BEGIN 61 | 62 | SELECT TOP 1 @OrderID = OrderID FROM #tmpOrderIDs 63 | IF @DEBUG = 1 PRINT @OrderID 64 | 65 | --Figure out the Customer 66 | SELECT @CustomerID = OrderCustomerID 67 | FROM COM_Order 68 | WHERE [OrderID] = @OrderID 69 | 70 | --Remove OrderItemSKUFile from this Order's Order Items 71 | --SELECT * FROM COM_OrderItemSKUFile WHERE [OrderItemID] IN ( 72 | DELETE FROM COM_OrderItemSKUFile WHERE [OrderItemID] IN ( 73 | SELECT [OrderItemID] 74 | FROM COM_OrderItem 75 | WHERE [OrderItemOrderID] = @OrderID 76 | ) 77 | 78 | --Remove Order Items from this Order's Order Items 79 | DELETE FROM COM_OrderItem WHERE [OrderItemOrderID] = @OrderID 80 | --SELECT * FROM COM_OrderItem WHERE [OrderItemOrderID] = @OrderID 81 | 82 | --Remove from the Order from the User's Order Status 83 | DELETE FROM COM_OrderStatusUser WHERE [OrderID] = @OrderID 84 | --SELECT * FROM COM_OrderStatusUser WHERE [OrderID] = @OrderID 85 | 86 | --Remove the Addresses of the Order 87 | DELETE FROM COM_OrderAddress WHERE [AddressOrderID] = @OrderID 88 | 89 | --Remove the Order 90 | DELETE FROM COM_Order WHERE [OrderID] = @OrderID 91 | --SELECT * FROM COM_Order WHERE [OrderID] = @OrderID 92 | 93 | IF @KeepCustomersAlive = 0 94 | BEGIN 95 | IF @DEBUG = 1 PRINT 'Attempting to Remove CustomerID '+ CONVERT(nvarchar(50), @CustomerID) 96 | 97 | --We just removed the last order for this customer, now we can remove the customer 98 | SELECT @TotalOrders = Count(OrderID) FROM COM_Order WHERE [OrderCustomerID] = @CustomerID 99 | IF @TotalOrders = 0 100 | BEGIN 101 | --Have to clear out the Shopping Cart references first 102 | DELETE COM_ShoppingCartSKU 103 | FROM COM_ShoppingCartSKU S 104 | INNER JOIN COM_ShoppingCart C ON 105 | S.ShoppingCartID = C.ShoppingCartID 106 | INNER JOIN COM_Customer CO ON 107 | C.ShoppingCartCustomerID = CO.CustomerID 108 | WHERE CO.CustomerID = @CustomerID 109 | 110 | DELETE COM_ShoppingCartCouponCode 111 | FROM COM_ShoppingCartCouponCode S 112 | INNER JOIN COM_ShoppingCart C ON 113 | S.ShoppingCartID = C.ShoppingCartID 114 | INNER JOIN COM_Customer CO ON 115 | C.ShoppingCartCustomerID = CO.CustomerID 116 | WHERE CO.CustomerID = @CustomerID 117 | 118 | DELETE COM_ShoppingCart WHERE ShoppingCartCustomerID = @CustomerID 119 | 120 | --Then clear out the addresses for this Customer 121 | DELETE COM_Address WHERE AddressCustomerID = @CustomerID 122 | 123 | --Finally! can remove the Customer 124 | DELETE COM_Customer WHERE CustomerID = @CustomerID 125 | 126 | SET @CustomersRemoved = @CustomersRemoved + 1 127 | IF @DEBUG = 1 PRINT 'Customer removed' 128 | END 129 | ELSE 130 | BEGIN 131 | PRINT 'Skipping as Customer still has orders' 132 | END 133 | 134 | END 135 | 136 | IF @DEBUG = 1 PRINT 'Deleted order ' + CONVERT(nvarchar(100), @OrderID) 137 | 138 | --Remove item from temp table to process 139 | DELETE FROM #tmpOrderIDs WHERE OrderID = @OrderID 140 | END 141 | 142 | SET NOCOUNT OFF 143 | 144 | DROP TABLE #tmpOrderIDs 145 | 146 | SELECT @TotalOrders = COUNT(OrderID) FROM COM_Order 147 | 148 | PRINT 'Removed ' + CONVERT(nvarchar(50), @BatchSize) + ' orders' 149 | Print 'Removed ' + CONVERT(nvarchar(50), @CustomersRemoved) + ' customers' 150 | PRINT 'Succcess. Total Orders Remain: ' + CONVERT(nvarchar(50), @TotalOrders) 151 | -------------------------------------------------------------------------------- /src/KX12/KenticoDeleteStagingData.v12.sql: -------------------------------------------------------------------------------- 1 | /* KenticoDeleteStagingDAta.v12.sql */ 2 | /* Goal: Clean up data from Content Staging */ 3 | /* Description: Truncates all Staging tasks */ 4 | /* that can bloat a database. Be very careful */ 5 | /* with this one, there is no coming back */ 6 | /* Intended Kentico Verison: 12.x */ 7 | /* Author: Brian McKeiver (mcbeev@gmail.com) */ 8 | /* Revision: 1.0 */ 9 | /* Take a backup first! Don't be THAT guy! */ 10 | 11 | TRUNCATE TABLE Staging_Synchronization 12 | 13 | GO 14 | 15 | DELETE FROM Staging_Task 16 | -------------------------------------------------------------------------------- /src/KX12/KenticoDisableTasksForDevSpinup.v12.sql: -------------------------------------------------------------------------------- 1 | /* KenticoDisableTasksForDevSpinup.v12.sql */ 2 | /* Goal: Create a safe dev instance from prod */ 3 | /* Description: Disable all scheduled tasks, */ 4 | /* remove SMTP server settings to ensure no */ 5 | /* emails go out, disable emails, and queue. */ 6 | /* Run this after your restore the DB and */ 7 | /* before you fire up the application code */ 8 | /* Intended Kentico Verison: 12.x */ 9 | /* Author: Brian McKeiver (mcbeev@gmail.com) */ 10 | /* Revision: 1.0 */ 11 | /* Take a backup first! Don't be THAT guy! */ 12 | 13 | --Disable all Scheduled Tasks 14 | UPDATE CMS_ScheduledTask SET TaskEnabled = 0 15 | 16 | --Remove all SMTP Servers from Additional SMTP servers 17 | TRUNCATE TABLE CMS_SMTPServerSite 18 | 19 | --Update Settings app to blank out main SMTP Settings 20 | UPDATE CMS_SettingsKey SET KeyValue = '' WHERE KeyName = 'CMSSMTPServer' 21 | UPDATE CMS_SettingsKey SET KeyValue = '' WHERE KeyName = 'CMSSMTPServerPassword' 22 | UPDATE CMS_SettingsKey SET KeyValue = '' WHERE KeyName = 'CMSSMTPServerUser' 23 | 24 | --Update Settings app to disable email and email queue 25 | UPDATE CMS_SettingsKey SET KeyValue = 'False' WHERE KeyName = 'CMSEmailsEnabled' 26 | UPDATE CMS_SettingsKey SET KeyValue = 'False' WHERE KeyName = 'CMSEmailQueueEnabled' 27 | 28 | --Disable all Content Staing Servers 29 | UPDATE Staging_Server SET ServerEnabled = 0 30 | 31 | --Disable all Web Farm Servers 32 | UPDATE CMS_WebFarmServer SET ServerEnabled = 0 33 | 34 | --Disable all Marketing Automation Processes 35 | UPDATE CMS_Workflow SET WorkflowEnabled = 0 WHERE ([WorkflowType] = 3) 36 | -------------------------------------------------------------------------------- /src/KX13/ConvertContainerPageTypeToCoupledWithUrl.v12.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------------------------------------------------------------------------------------- 2 | ----------- Container to Coupled Page Type Converter for KX13 (by Trevor Fayas - github.com/kenticodevtrev ------------- 3 | -------------------------------------------------------------------------------------------------------------------------- 4 | 5 | -------------------------------------------------------------------------------------------------------------------------- 6 | -- KX13 does not have Containered Page Types, generally (they exist but you can't create them). 7 | -- Coupled with this, many Containered page types (such as folders) in KX12 still were used as part of the URL structure 8 | -- generation. Since during the KX12 to KX13 upgrade, any page types with an empty or null ClassURLPattern have the URL 9 | -- featured disabled and are not included thus in URL generation for any child elements, this can cause issues with old 10 | -- URLs no longer existing. An example is if you have a page with NodeAliasPath /Articles/2020/May/Hello, and the 11 | -- 2020 and May elements are folders (or any page type without a ClassURLPattern), KX 12 will make the url 12 | -- /Articles/Hello instead of it's original URL of /Articles/2020/May/Hello 13 | -- 14 | -- Whlie it is best to fix this before upgrade, sometimes that's no longer an option. This script will switch the Container 15 | -- page type to a Coupled Page Type, create the binding tables, handle initial Url Generation. If you need help 'cleaning' 16 | -- up the URLs after you do this to try to fix existing issues, please contact tfayas@hbs.net, i have a script that can 17 | -- rebuild the URLs in KX13. 18 | -------------------------------------------------------------------------------------------------------------------------- 19 | 20 | -------------------------------------------------------------------------------------------------------------------------- 21 | ---------------------------- ALWAYS BACK UP BEFORE RUNNING: Don't be that guy! ------------------------------------------- 22 | ---------------------- Also in Kentico do a System -> Clear Cache / Restart Application after----------------------------- 23 | -------------------------------------------------------------------------------------------------------------------------- 24 | 25 | -- MODIFY THESE 4 26 | declare @Namespace nvarchar(100) = 'Generic' 27 | declare @Name nvarchar(100) = 'Folder' 28 | declare @CulturePrefix bit = 1; 29 | declare @NoPrefixOnDefaultCulture bit = 1; 30 | 31 | -- Do not modify below 32 | declare @ClassName nvarchar(200); 33 | declare @TableName nvarchar(200); 34 | declare @FormIDFieldGuid nvarchar(50); 35 | declare @FormNameFieldGuid nvarchar(50); 36 | declare @FormIDSearchFieldGuid nvarchar(50); 37 | declare @FormNameSearchFieldGuid nvarchar(50); 38 | set @ClassName = @Namespace+'.'+@Name 39 | set @TableName = @Namespace+'_'+@Name 40 | set @FormIDFieldGuid = LOWER(Convert(nvarchar(50), NewID())); 41 | set @FormNameFieldGuid = LOWER(Convert(nvarchar(50), NewID())); 42 | set @FormIDSearchFieldGuid = LOWER(Convert(nvarchar(50), NewID())); 43 | set @FormNameSearchFieldGuid = LOWER(Convert(nvarchar(50), NewID())); 44 | 45 | -- Update Class 46 | update CMS_Class set 47 | ClassIsDocumentType = 1, 48 | ClassIsCoupledClass = 1, 49 | ClassXmlSchema = ' 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 | ClassFormDefinition = '
'+@Name+'IDNameFalseFalseFalseTextBoxControlFalseFalse
', 77 | ClassNodeNameSource = 'Name', 78 | ClassTableName = @TableName, 79 | ClassShowTemplateSelection = null, 80 | ClassIsMenuItemType = null, 81 | ClassSearchTitleColumn = 'DocumentName', 82 | ClassSearchCreationDateColumn = 'DocumentCreatedWhen', 83 | ClassSearchSettings = '', 84 | ClassSearchEnabled = 1, 85 | ClassUsesPageBuilder = 0, 86 | ClassIsNavigationItem = 0, 87 | ClassHasURL = 1, 88 | ClassHasMetadata = 0 89 | where ClassName = @ClassName 90 | 91 | -- Create table 92 | declare @CreateTable nvarchar(max); 93 | set @CreateTable = ' 94 | CREATE TABLE [dbo].['+@TableName+']( 95 | ['+@Name+'ID] [int] IDENTITY(1,1) NOT NULL, 96 | [Name] [nvarchar](200) NOT NULL, 97 | CONSTRAINT [PK_'+@TableName+'] PRIMARY KEY CLUSTERED 98 | ( 99 | ['+@Name+'ID] ASC 100 | )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] 101 | ) ON [PRIMARY] 102 | 103 | ALTER TABLE [dbo].['+@TableName+'] ADD CONSTRAINT [DEFAULT_'+@TableName+'_Name] DEFAULT (N'''') FOR [Name]' 104 | exec(@CreateTable); 105 | 106 | -- Populate joining table data, as well as generate the default url path entry based on nodealiaspath 107 | declare @BindingAndVersionSQL nvarchar(max); 108 | 109 | set @BindingAndVersionSQL = ' 110 | declare @ClassName nvarchar(200); 111 | declare @TableName nvarchar(200); 112 | declare @documentid int; 113 | declare @documentname nvarchar(200); 114 | declare @documentculture nvarchar(10); 115 | declare @NodeGuidPostfix nvarchar(50); 116 | declare @UrlPath nvarchar(500); 117 | declare @UrlPathCulturePrefix nvarchar(50); 118 | declare @UrlPathPostfix nvarchar(100); 119 | declare @NodeID int; 120 | declare @SiteID int; 121 | declare @newrowid int; 122 | declare @UrlExistingMatches int; 123 | declare @UrlPathComplete nvarchar(500); 124 | 125 | set @ClassName = '''+@Namespace+'.'+@Name+''' 126 | set @TableName = '''+@Namespace+'_'+@Name+''' 127 | 128 | declare contenttable_cursor cursor for 129 | 130 | select * from ( 131 | select 132 | COALESCE(D.DocumentID, NoCultureD.DocumentID) as DocumentID, 133 | COALESCE(D.DocumentName, NoCultureD.DocumentName) as DocumentName, 134 | C.CultureCode, 135 | NodeID, 136 | NodeSiteID, 137 | RIGHT(NodeAliasPath, len(NodeAliasPath)-1) as UrlPath, 138 | case when 1='+Convert(nvarchar(1), @CulturePrefix)+' and (0='+Convert(nvarchar(1), @NoPrefixOnDefaultCulture)+' or C.CultureCode <> SiteDefaultVisitorCulture) then C.CultureCode+''/'' else '''' end as CulturePrefix, 139 | LOWER(''-''+REPLACE(Convert(nvarchar(100), NodeGuid),''-'', '''')) as NodeGuidPostfix 140 | from CMS_Site S 141 | left join CMS_SiteCulture SC on SC.SiteID = S.SiteID 142 | left join CMS_Culture C on C.CultureID = SC.CultureID 143 | left join CMS_Tree on NodeSiteID = S.SiteID 144 | left join CMS_Class on ClassID = NodeClassID 145 | left outer join CMS_Document D on D.DocumentNodeID = NodeID and D.DocumentCulture = C.CultureCode 146 | left outer join CMS_Document NoCultureD on NoCultureD.DocumentNodeID = NodeID 147 | where ClassName = @ClassName 148 | ) cultureAcross 149 | group by DocumentID, DocumentName, CultureCode, NodeID, NodeSiteID, UrlPath, CulturePrefix, NodeGuidpostFix 150 | order by UrlPath 151 | 152 | open contenttable_cursor 153 | fetch next from contenttable_cursor into @documentid, @documentname, @documentculture, @NodeID, @SiteID, @UrlPath, @UrlPathCulturePrefix, @UrlPathPostfix 154 | 155 | WHILE @@FETCH_STATUS = 0 BEGIN 156 | 157 | -- insert into binding table -- 158 | INSERT INTO [dbo].['+@TableName+'] ([Name]) VALUES (@documentname) 159 | 160 | -- Update document -- 161 | set @newrowid = SCOPE_IDENTITY(); 162 | update CMS_Document set DocumentForeignKeyValue = @newrowid where DocumentID = @documentid 163 | 164 | -- update also history -- 165 | update CMS_VersionHistory set NodeXML = replace(NodeXML, ''''+CONVERT(nvarchar(10), @documentid)+'''', ''''+CONVERT(nvarchar(10), @documentid)+''''+CONVERT(nvarchar(10), @newrowid)+'''') where DocumentID = @documentid 166 | 167 | --------------------------------- 168 | -- Create initial UrlPagePaths -- 169 | --------------------------------- 170 | set @UrlPathComplete = @UrlPathCulturePrefix+@UrlPath; 171 | 172 | -- Add guid postfix if match on the page url path exists. 173 | set @UrlExistingMatches = (select count(*) from CMS_PageUrlPath where PageUrlPathUrlPath = @UrlPathCulturePrefix+@UrlPath) 174 | if @URLExistingMatches > 0 begin 175 | set @UrlPathComplete = @UrlPathComplete+@UrlPathPostfix 176 | end 177 | 178 | -- If conflict on alternative url, then handle as well 179 | set @UrlExistingMatches = (select count(*) from CMS_AlternativeUrl where CONVERT(NVARCHAR(64), HASHBYTES(''SHA2_256'', LOWER(AlternativeUrlUrl)), 2) = CONVERT(VARCHAR(64), HASHBYTES(''SHA2_256'', LOWER(@UrlPathComplete)), 2) and AlternativeUrlSiteID = @SiteID) 180 | if @URLExistingMatches > 0 begin 181 | set @UrlPathComplete = @UrlPathComplete+''-''+Convert(nvarchar(100), NewID()) 182 | end 183 | 184 | INSERT INTO [dbo].[CMS_PageUrlPath] 185 | ([PageUrlPathGUID] 186 | ,[PageUrlPathCulture] 187 | ,[PageUrlPathNodeID] 188 | ,[PageUrlPathUrlPath] 189 | ,[PageUrlPathUrlPathHash] 190 | ,[PageUrlPathSiteID] 191 | ,[PageUrlPathLastModified]) 192 | VALUES 193 | (NEWID() 194 | ,@documentculture 195 | ,@NodeID 196 | ,@UrlPathComplete 197 | ,CONVERT(VARCHAR(64), HASHBYTES(''SHA2_256'', LOWER(@UrlPathComplete)), 2) 198 | ,@SiteID 199 | ,GETDATE()) 200 | 201 | FETCH NEXT FROM contenttable_cursor into @documentid, @documentname, @documentculture, @NodeID, @SiteID, @UrlPath, @UrlPathCulturePrefix, @UrlPathPostfix 202 | END 203 | Close contenttable_cursor 204 | DEALLOCATE contenttable_cursor' 205 | exec(@BindingAndVersionSQL) -------------------------------------------------------------------------------- /src/KX13/ConvertPageTypeToUrl.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------------------------------------------------------------------------------------- 2 | ----------- Page Type Converter for KX13 (by Trevor Fayas - github.com/kenticodevtrev ------------- 3 | -------------------------------------------------------------------------------------------------------------------------- 4 | 5 | -------------------------------------------------------------------------------------------------------------------------- 6 | -- KX13 does not allow you to enable the URL feature on a page type through the UI. If your page type is not a container 7 | -- (if it is, use the ConvertContainerPageTypeToCoupledWIthurl script), and you simply need to enable Url / page builder 8 | -- functionality, this script will do this and insert the appropriate UrlPaths into the CMS_PageUrlPath table. 9 | -- 10 | -- This script assumes that the page types ABOVE these classes have Url Enabled, if not then you'll need to adjust the 11 | -- Page Url Path script to somehow account for it. 12 | -- 13 | -- Also this does not generate any staging tasks, so this will need to be run on each environment, followed by a System -> 14 | -- Clear Cache and Restart Application. 15 | -------------------------------------------------------------------------------------------------------------------------- 16 | 17 | -------------------------------------------------------------------------------------------------------------------------- 18 | ---------------------------- ALWAYS BACK UP BEFORE RUNNING: Don't be that guy! ------------------------------------------- 19 | ---------------------- Also in Kentico do a System -> Clear Cache / Restart Application after----------------------------- 20 | -------------------------------------------------------------------------------------------------------------------------- 21 | 22 | Declare @ClassName nvarchar(100) = 'my.customclass' 23 | declare @EnablePageBuilder bit = 0 24 | declare @EnableMetaData bit = 1 25 | declare @MakeMenuItemType bit = 0 26 | declare @PrefixCulture bit = 0 27 | 28 | -- Set Features 29 | update CMS_Class set ClassHasURL = 1, ClassIsMenuItemType = @MakeMenuItemType, ClassURLPattern = '{% NodeAliasPath %}', ClassUsesPageBuilder = @EnablePageBuilder, ClassHasMetadata = @EnableMetaData where ClassName = @ClassName 30 | 31 | -- Insert PageUrlPaths 32 | INSERT INTO [dbo].[CMS_PageUrlPath] 33 | ([PageUrlPathGUID] 34 | ,[PageUrlPathCulture] 35 | ,[PageUrlPathNodeID] 36 | ,[PageUrlPathUrlPath] 37 | ,[PageUrlPathUrlPathHash] 38 | ,[PageUrlPathSiteID] 39 | ,[PageUrlPathLastModified]) 40 | select 41 | NEWID() as [PageUrlPathGUID], 42 | DocumentCulture as [PageUrlPathCulture], 43 | NodeID as [PageUrlPathNodeID], 44 | case when @PrefixCulture = 1 then '/'+DocumentCulture+NodeAliasPath else NodeAliasPath end as [PageUrlPathUrlPath], 45 | CONVERT(VARCHAR(64), HASHBYTES('SHA2_256', LOWER(case when @PrefixCulture = 1 then '/'+DocumentCulture+NodeAliasPath else NodeAliasPath end)), 2) as [PageUrlPathUrlPathHash], 46 | NodeSiteID as [PageUrlPathSiteID], 47 | GETDATE() AS [PageUrlPathLastModified] 48 | 49 | from View_CMS_Tree_Joined where ClassName = @ClassName 50 | order by NodeSiteID, NodeAliasPath 51 | -------------------------------------------------------------------------------- /src/KX13/GetAllResourceStringsForEveryLanguageOnTheSite.v13.sql: -------------------------------------------------------------------------------- 1 | 2 | DECLARE @id INT 3 | DECLARE @name NVARCHAR(100) 4 | DECLARE @getid CURSOR 5 | 6 | create table #TempResourceStrings ( 7 | ResourceID int, 8 | ResourceKey nvarchar(150), 9 | ResourceLangCode nvarchar(5), 10 | ResourceName nvarchar(100), 11 | ResourceValue nvarchar(max) 12 | ) 13 | 14 | SET @getid = CURSOR FOR 15 | select StringID, StringKey 16 | from CMS_ResourceString 17 | 18 | OPEN @getid 19 | FETCH NEXT 20 | FROM @getid INTO @id, @name 21 | WHILE @@FETCH_STATUS = 0 22 | BEGIN 23 | insert into #TempResourceStrings (ResourceID, ResourceKey, ResourceLangCode, ResourceName, ResourceValue) 24 | select @id, @name, c.CultureCode, c.CultureShortName, (select TranslationText from CMS_ResourceTranslation rt where c.CultureID = rt.TranslationCultureID AND rt.TranslationStringID = @id) 25 | from CMS_Culture c 26 | inner join CMS_SiteCulture sc on c.CultureID = sc.CultureID 27 | FETCH NEXT 28 | FROM @getid INTO @id, @name 29 | END 30 | 31 | select * 32 | from #TempResourceStrings 33 | ORDER BY ResourceKey 34 | 35 | drop table #TempResourceStrings 36 | CLOSE @getid 37 | DEALLOCATE @getid 38 | -------------------------------------------------------------------------------- /src/KX13/Manual-OM-DBSeparation/1-Remove-Procedures.sql: -------------------------------------------------------------------------------- 1 | DECLARE @ObjectName nvarchar(500) 2 | 3 | DECLARE CurName CURSOR FAST_FORWARD READ_ONLY 4 | FOR 5 | 6 | SELECT name 7 | FROM sys.sql_modules m 8 | INNER JOIN sys.objects o 9 | ON m.object_id=o.object_id 10 | WHERE type_desc like '%procedure%' and name not in 11 | ( 12 | -- Defined in CMS/App_Data/DBSeparation/procedures_functions_views.txt 13 | 'Proc_OM_Account_MassDelete', 14 | 'Proc_OM_Account_UpdatePrimaryContact', 15 | 'Proc_OM_AccountContact_AccountsIntoContact', 16 | 'Proc_OM_AccountContact_ContactsIntoAccount', 17 | 'Proc_OM_Activity_BulkInsertActivities', 18 | 'Proc_OM_ActivityRecalculationQueue_FetchActivityIDs', 19 | 'Proc_OM_ContactChangeRecalculationQueue_FetchContactChanges', 20 | 'Proc_OM_Contact_MassDelete', 21 | 'Proc_OM_Contact_RemoveCustomer', 22 | 'Proc_OM_ContactGroupMember_AddContactIntoAccount', 23 | 'Proc_OM_ContactGroupMember_AddContactsToContactGroupDynamic', 24 | 'Proc_OM_ContactGroupMember_AddContactToContactGroupsDynamic', 25 | 'Proc_OM_ContactGroupMember_RemoveAccountContacts', 26 | 'Proc_OM_ContactGroupMember_RemoveContactsFromAccount', 27 | 'Proc_OM_ContactGroupMember_UpdateMembersForAccount', 28 | 'Proc_OM_Score_UpdateContactScore', 29 | 'Proc_OM_ScoreContactRule_AddContacts', 30 | 'Proc_Personas_ReevaluateAllContacts' 31 | ) 32 | 33 | OPEN CurName 34 | 35 | FETCH NEXT FROM CurName INTO @ObjectName 36 | 37 | WHILE @@FETCH_STATUS = 0 38 | BEGIN 39 | exec('DROP PROCEDURE '+@ObjectName); 40 | 41 | FETCH NEXT FROM CurName INTO @ObjectName 42 | END 43 | 44 | CLOSE CurName 45 | DEALLOCATE CurName 46 | -------------------------------------------------------------------------------- /src/KX13/Manual-OM-DBSeparation/2-Remove-Views.sql: -------------------------------------------------------------------------------- 1 | DECLARE @ObjectName nvarchar(500) 2 | 3 | DECLARE CurName CURSOR FAST_FORWARD READ_ONLY 4 | FOR 5 | 6 | SELECT name 7 | FROM sys.sql_modules m 8 | INNER JOIN sys.objects o 9 | ON m.object_id=o.object_id 10 | WHERE type_desc like '%view%' and name not in 11 | ( 12 | -- Defined in CMS/App_Data/DBSeparation/procedures_functions_views.txt 13 | 'View_OM_Account_Joined', 14 | 'View_OM_AccountContact_ContactJoined', 15 | 'View_OM_AccountContact_AccountJoined', 16 | 'View_OM_ContactGroupMember_AccountJoined' 17 | ) 18 | 19 | OPEN CurName 20 | 21 | FETCH NEXT FROM CurName INTO @ObjectName 22 | 23 | WHILE @@FETCH_STATUS = 0 24 | BEGIN 25 | exec('DROP VIEW '+@ObjectName); 26 | 27 | FETCH NEXT FROM CurName INTO @ObjectName 28 | END 29 | 30 | CLOSE CurName 31 | DEALLOCATE CurName 32 | -------------------------------------------------------------------------------- /src/KX13/Manual-OM-DBSeparation/3-Remove-OM-Foreign-Keys.sql: -------------------------------------------------------------------------------- 1 | -- Delete Foreign keys that the OM tables reference 2 | DECLARE @FKTable nvarchar(500) 3 | DECLARE @FKName nvarchar(500) 4 | 5 | DECLARE CurName CURSOR FAST_FORWARD READ_ONLY 6 | FOR 7 | 8 | select t.name as TableWithForeignKey, fk.name as FKname 9 | from sys.foreign_key_columns as c 10 | inner join sys.tables as t on c.parent_object_id = t.object_id 11 | inner join sys.objects as fk on c.constraint_object_id = fk.object_id 12 | inner join sys.columns as col on c.parent_object_id = col.object_id and c.parent_column_id = col.column_id 13 | inner join sys.tables as pkt on pkt.object_id = c.referenced_object_id 14 | inner join INFORMATION_SCHEMA.TABLE_CONSTRAINTS tc on tc.TABLE_NAME = pkt.name AND tc.CONSTRAINT_TYPE = 'PRIMARY KEY' 15 | inner join INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE ccu ON tc.CONSTRAINT_NAME = ccu.Constraint_name 16 | where pkt.name in ( 17 | -- Defined in CMS/App_Data/DBSeparation/temporary_tables.txt (just the table name, not ID field) 18 | 'CMS_Country', 19 | 'CMS_State', 20 | 'CMS_User', 21 | 'CMS_Site', 22 | 'Newsletter_NewsletterIssue', 23 | 'Newsletter_Subscriber' 24 | ) 25 | 26 | OPEN CurName 27 | 28 | FETCH NEXT FROM CurName INTO @FKTable, @FKName 29 | 30 | WHILE @@FETCH_STATUS = 0 31 | BEGIN 32 | exec('alter table ['+@FKTable+'] drop ['+@FKName+']') 33 | 34 | FETCH NEXT FROM CurName INTO @FKTable, @FKName 35 | END 36 | 37 | CLOSE CurName 38 | DEALLOCATE CurName 39 | -------------------------------------------------------------------------------- /src/KX13/Manual-OM-DBSeparation/4-Remove-Other-Foreign-Key.sql: -------------------------------------------------------------------------------- 1 | -- Delete Foreign keys that will prevent table deletion 2 | DECLARE @FKTable nvarchar(500) 3 | DECLARE @FKName nvarchar(500) 4 | 5 | DECLARE CurName CURSOR FAST_FORWARD READ_ONLY 6 | FOR 7 | 8 | select t.name as TableWithForeignKey, fk.name as FKname 9 | from sys.foreign_key_columns as c 10 | inner join sys.tables as t on c.parent_object_id = t.object_id 11 | inner join sys.objects as fk on c.constraint_object_id = fk.object_id 12 | inner join sys.columns as col on c.parent_object_id = col.object_id and c.parent_column_id = col.column_id 13 | inner join sys.tables as pkt on pkt.object_id = c.referenced_object_id 14 | inner join INFORMATION_SCHEMA.TABLE_CONSTRAINTS tc on tc.TABLE_NAME = pkt.name AND tc.CONSTRAINT_TYPE = 'PRIMARY KEY' 15 | inner join INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE ccu ON tc.CONSTRAINT_NAME = ccu.Constraint_name 16 | where pkt.name in ( 17 | 'CMS_Resource' 18 | ) 19 | 20 | OPEN CurName 21 | 22 | FETCH NEXT FROM CurName INTO @FKTable, @FKName 23 | 24 | WHILE @@FETCH_STATUS = 0 25 | BEGIN 26 | exec('alter table ['+@FKTable+'] drop ['+@FKName+']') 27 | 28 | FETCH NEXT FROM CurName INTO @FKTable, @FKName 29 | END 30 | 31 | CLOSE CurName 32 | DEALLOCATE CurName 33 | -------------------------------------------------------------------------------- /src/KX13/Manual-OM-DBSeparation/5-Remove-Tables.sql: -------------------------------------------------------------------------------- 1 | -- Delete tables 2 | -- MUST RUN MULTIPLE TIMES (like 3), as foreign keys prevent some tables from deleting, which will succeed the next time. 3 | DECLARE @ObjectName nvarchar(500) 4 | 5 | DECLARE CurName CURSOR FAST_FORWARD READ_ONLY 6 | FOR 7 | 8 | SELECT name 9 | from sys.objects s 10 | WHERE type = 'U' and name not in 11 | ( 12 | -- Defined in CMS/App_Data/DBSeparation/tables.txt 13 | 'OM_ContactStatus', 14 | 'OM_Contact', 15 | 'OM_AccountStatus', 16 | 'OM_Account', 17 | 'OM_ContactRole', 18 | 'OM_AccountContact', 19 | 'OM_ActivityType', 20 | 'OM_Activity', 21 | 'OM_ActivityRecalculationQueue', 22 | 'OM_ContactChangeRecalculationQueue', 23 | 'OM_ContactGroup', 24 | 'OM_ContactGroupMember', 25 | 'Personas_Persona', 26 | 'Personas_PersonaContactHistory', 27 | 'OM_Score', 28 | 'OM_Rule', 29 | 'OM_ScoreContactRule', 30 | 'OM_Membership', 31 | 'OM_VisitorToContact', 32 | 'Newsletter_OpenedEmail', 33 | 'Newsletter_Link', 34 | 'Newsletter_ClickedLink', 35 | 'Newsletter_IssueContactGroup', 36 | 'CMS_Consent', 37 | 'CMS_ConsentArchive', 38 | 'CMS_ConsentAgreement' 39 | ) order by 40 | ( 41 | SELECT 42 | count(*) 43 | FROM 44 | sys.foreign_keys AS f 45 | INNER JOIN 46 | sys.foreign_key_columns AS fc 47 | ON f.OBJECT_ID = fc.constraint_object_id 48 | INNER JOIN 49 | sys.tables t 50 | ON t.OBJECT_ID = fc.referenced_object_id 51 | WHERE 52 | OBJECT_NAME (f.referenced_object_id) = s.name 53 | ) 54 | 55 | OPEN CurName 56 | 57 | FETCH NEXT FROM CurName INTO @ObjectName 58 | 59 | WHILE @@FETCH_STATUS = 0 60 | BEGIN 61 | exec('DROP TABLE '+@ObjectName); 62 | 63 | FETCH NEXT FROM CurName INTO @ObjectName 64 | END 65 | 66 | CLOSE CurName 67 | DEALLOCATE CurName 68 | -------------------------------------------------------------------------------- /src/KX13/Manual-OM-DBSeparation/6-Remove-Functions.sql: -------------------------------------------------------------------------------- 1 | DECLARE @ObjectName nvarchar(500) 2 | 3 | DECLARE CurName CURSOR FAST_FORWARD READ_ONLY 4 | FOR 5 | 6 | SELECT name 7 | FROM sys.sql_modules m 8 | INNER JOIN sys.objects o 9 | ON m.object_id=o.object_id 10 | WHERE type_desc like '%function%' and name not in 11 | ( 12 | -- Defined in CMS/App_Data/DBSeparation/procedures_functions_views.txt 13 | 'Func_OM_Account_GetSubsidiaries', 14 | 'Func_OM_Account_GetSubsidiaryOf' 15 | ) 16 | 17 | OPEN CurName 18 | 19 | FETCH NEXT FROM CurName INTO @ObjectName 20 | 21 | WHILE @@FETCH_STATUS = 0 22 | BEGIN 23 | exec('DROP FUNCTION '+@ObjectName); 24 | 25 | FETCH NEXT FROM CurName INTO @ObjectName 26 | END 27 | 28 | CLOSE CurName 29 | DEALLOCATE CurName 30 | -------------------------------------------------------------------------------- /src/KX13/Manual-OM-DBSeparation/7-Remove-Table-Types.sql: -------------------------------------------------------------------------------- 1 | -- Remove user defined table types 2 | DECLARE @ObjectName nvarchar(500) 3 | 4 | DECLARE CurName CURSOR FAST_FORWARD READ_ONLY 5 | FOR 6 | 7 | select name from sys.types 8 | where is_user_defined = 1 and name not in 9 | ( 10 | -- Defined in CMS/App_Data/DBSeparation/copy_types.txt 11 | 'Type_CMS_IntegerTable', 12 | 'Type_CMS_OrderedIntegerTable', 13 | 'Type_CMS_BigIntTable', 14 | 'Type_CMS_GuidTable', 15 | 'Type_CMS_StringTable', 16 | 'Type_OM_ActivityTable', 17 | 'Type_OM_ContactEmailTable', 18 | 'Type_OM_OrderedIntegerTable_DuplicatesAllowed' 19 | ) 20 | 21 | OPEN CurName 22 | 23 | FETCH NEXT FROM CurName INTO @ObjectName 24 | 25 | WHILE @@FETCH_STATUS = 0 26 | BEGIN 27 | exec('DROP TYPE '+@ObjectName); 28 | 29 | FETCH NEXT FROM CurName INTO @ObjectName 30 | END 31 | 32 | CLOSE CurName 33 | DEALLOCATE CurName 34 | -------------------------------------------------------------------------------- /src/KX13/Manual-OM-DBSeparation/Cleanup-1-Remove-OM-Tables.sql: -------------------------------------------------------------------------------- 1 | -- Delete tables 2 | -- MUST RUN MULTIPLE TIMES (like 3), as foreign keys prevent some tables from deleting, which will succeed the next time. 3 | DECLARE @ObjectName nvarchar(500) 4 | 5 | DECLARE CurName CURSOR FAST_FORWARD READ_ONLY 6 | FOR 7 | 8 | SELECT * from STRING_SPLIT( 9 | -- Defined in CMS/App_Data/DBSeparation/tables.txt - IN REVERSE ORDER! 10 | 'CMS_ConsentAgreement 11 | CMS_ConsentArchive 12 | CMS_Consent 13 | Newsletter_IssueContactGroup 14 | Newsletter_ClickedLink 15 | Newsletter_Link 16 | Newsletter_OpenedEmail 17 | OM_VisitorToContact 18 | OM_Membership 19 | OM_ScoreContactRule 20 | OM_Rule 21 | OM_Score 22 | Personas_PersonaContactHistory 23 | Personas_Persona 24 | OM_ContactGroupMember 25 | OM_ContactGroup 26 | OM_ContactChangeRecalculationQueue 27 | OM_ActivityRecalculationQueue 28 | OM_Activity 29 | OM_ActivityType 30 | OM_AccountContact 31 | OM_ContactRole 32 | OM_Account 33 | OM_AccountStatus 34 | OM_Contact 35 | OM_ContactStatus' 36 | ,CHAR(13)) 37 | 38 | OPEN CurName 39 | 40 | FETCH NEXT FROM CurName INTO @ObjectName 41 | 42 | WHILE @@FETCH_STATUS = 0 43 | BEGIN 44 | exec('DROP TABLE '+@ObjectName); 45 | 46 | FETCH NEXT FROM CurName INTO @ObjectName 47 | END 48 | 49 | CLOSE CurName 50 | DEALLOCATE CurName 51 | -------------------------------------------------------------------------------- /src/KX13/Manual-OM-DBSeparation/Cleanup-2-Remove-OM-Functions.sql: -------------------------------------------------------------------------------- 1 | -- Delete Functions from Main Table 2 | DECLARE @ObjectName nvarchar(500) 3 | 4 | DECLARE CurName CURSOR FAST_FORWARD READ_ONLY 5 | FOR 6 | 7 | SELECT * from STRING_SPLIT( 8 | -- Defined in CMS/App_Data/DBSeparation/procedures_functions_views.txt - IN REVERSE ORDER! 9 | 'Func_OM_Account_GetSubsidiaryOf 10 | Func_OM_Account_GetSubsidiaries' 11 | ,CHAR(13)) 12 | 13 | OPEN CurName 14 | 15 | FETCH NEXT FROM CurName INTO @ObjectName 16 | 17 | WHILE @@FETCH_STATUS = 0 18 | BEGIN 19 | exec('DROP FUNCTION '+@ObjectName); 20 | 21 | FETCH NEXT FROM CurName INTO @ObjectName 22 | END 23 | 24 | CLOSE CurName 25 | DEALLOCATE CurName 26 | -------------------------------------------------------------------------------- /src/KX13/Manual-OM-DBSeparation/Cleanup-3-Remove-OM-Views.sql: -------------------------------------------------------------------------------- 1 | -- Delete Functions from Main Table 2 | DECLARE @ObjectName nvarchar(500) 3 | 4 | DECLARE CurName CURSOR FAST_FORWARD READ_ONLY 5 | FOR 6 | 7 | SELECT * from STRING_SPLIT( 8 | -- Defined in CMS/App_Data/DBSeparation/procedures_functions_views.txt - IN REVERSE ORDER! 9 | 'View_OM_ContactGroupMember_AccountJoined 10 | View_OM_AccountContact_AccountJoined 11 | View_OM_AccountContact_ContactJoined 12 | View_OM_Account_Joined' 13 | ,CHAR(13)) 14 | 15 | OPEN CurName 16 | 17 | FETCH NEXT FROM CurName INTO @ObjectName 18 | 19 | WHILE @@FETCH_STATUS = 0 20 | BEGIN 21 | exec('DROP VIEW '+@ObjectName); 22 | 23 | FETCH NEXT FROM CurName INTO @ObjectName 24 | END 25 | 26 | CLOSE CurName 27 | DEALLOCATE CurName 28 | -------------------------------------------------------------------------------- /src/KX13/Manual-OM-DBSeparation/Cleanup-4-Remove-OM-Stored-Procedures.sql: -------------------------------------------------------------------------------- 1 | -- Delete Functions from Main Table 2 | DECLARE @ObjectName nvarchar(500) 3 | 4 | DECLARE CurName CURSOR FAST_FORWARD READ_ONLY 5 | FOR 6 | 7 | SELECT * from STRING_SPLIT( 8 | -- Defined in CMS/App_Data/DBSeparation/procedures_functions_views.txt - IN REVERSE ORDER! 9 | 'Proc_Personas_ReevaluateAllContacts 10 | Proc_OM_ScoreContactRule_AddContacts 11 | Proc_OM_Score_UpdateContactScore 12 | Proc_OM_ContactGroupMember_UpdateMembersForAccount 13 | Proc_OM_ContactGroupMember_RemoveContactsFromAccount 14 | Proc_OM_ContactGroupMember_RemoveAccountContacts 15 | Proc_OM_ContactGroupMember_AddContactToContactGroupsDynamic 16 | Proc_OM_ContactGroupMember_AddContactsToContactGroupDynamic 17 | Proc_OM_ContactGroupMember_AddContactIntoAccount 18 | Proc_OM_Contact_RemoveCustomer 19 | Proc_OM_Contact_MassDelete 20 | Proc_OM_ContactChangeRecalculationQueue_FetchContactChanges 21 | Proc_OM_ActivityRecalculationQueue_FetchActivityIDs 22 | Proc_OM_Activity_BulkInsertActivities 23 | Proc_OM_AccountContact_ContactsIntoAccount 24 | Proc_OM_AccountContact_AccountsIntoContact 25 | Proc_OM_Account_UpdatePrimaryContact 26 | Proc_OM_Account_MassDelete' 27 | ,CHAR(13)) 28 | 29 | OPEN CurName 30 | 31 | FETCH NEXT FROM CurName INTO @ObjectName 32 | 33 | WHILE @@FETCH_STATUS = 0 34 | BEGIN 35 | exec('DROP PROCEDURE '+@ObjectName); 36 | 37 | FETCH NEXT FROM CurName INTO @ObjectName 38 | END 39 | 40 | CLOSE CurName 41 | DEALLOCATE CurName 42 | -------------------------------------------------------------------------------- /src/KX13/Manual-OM-DBSeparation/readme.md: -------------------------------------------------------------------------------- 1 | # Database Separation (Manually, no downtime) 2 | 3 | If you are leveraging Online Marketing features in KX13, it is often needed to separate the Online Marketing Database for high traffic sites in order to prevent degraded database performance. 4 | 5 | Kentico provides [documentation and methods](https://docs.xperience.io/on-line-marketing-features/configuring-and-customizing-your-on-line-marketing-features/separating-the-contact-management-database) to do this, however it requires that the site go down, and has a risk of prolonged downtime. It also doesn't allow copying of data for Azure. 6 | 7 | These scripts provide a way to manually separate the database without downtime, and also solves issues the issue of keeping your marketing data in an Azure Environment. 8 | 9 | The only caveout is you will lose marketing data that occurs between the time you Clone the main database and when you push the new CMSOMConnectionString, if that concerns you then you will need to take your sites offline or disable online marketing during that time. 10 | 11 | ## How it works 12 | 13 | Before I explain how this works, it's important to understand how the normal Kentico method works in database separation: 14 | 15 | 1. Turns off Scheduled Tasks 16 | 1. Sets a flag that causes your live site application to redirect all incoming requests to a `site down` type of page. (site goes 'offline') 17 | 1. Creates (or you create) a database with the correct Collation (`Latin1_General_CI_AS`, which hopefully is the collation of your database...) 18 | 1. Connects to the new OM Database 19 | 1. Creates Temporary Tables (`/CMS/App_Data/DBSeparation/temporary_tables.txt`) which the OM tables reference 20 | 1. Creates User Defined Table Types (`/CMS/App_Data/DBSeparation/copy_types.txt`) 21 | 1. Creates the OM tables (`/CMS/App_Data/DBSeparation/tables.txt` and `/CMS/App_Data/CMSInstall/SQL.zip/Objects/XXXX.xml`) in the database 22 | 1. Checks the existing CMS_Class on the OM Tables to add / update any fields that were customized by you and applies them to the om database tables 23 | 1. Adds Stored Procedures, Views, Functions (`/CMS/App_Data/DBSeparation/procedures_functions_views.txt`) 24 | 1. Strips Foreign Key constraints on the OM Tables from the Temporary Tables 25 | 1. Deletes the Temporary Tables 26 | 1. If possible (not on azure)... 27 | 1. copies data over 28 | 1. deletes the OM Tables from the main database (and related objects) 29 | 1. If database supports linked servers, run `/CMS/App_Data/DBSeparation/linked_server.txt` with various `##VALUE##` replaced with the `Main` and `OM` database names 30 | 31 | 32 | These scripts take the opposite approach. Instead of creating the database, tables, and copying data it, it starts with a full database and removes the other items. 33 | 34 | ## Procedure 35 | 36 | 1. BACKUP YOUR MAIN DATABASE (Don't be that guy...) 37 | 1. Clone the main database (the clone will be the separated OM database), then on the cloned database... 38 | 1. Run `1-Remove-Procedures.sql`, if necessary updating the query with the contents of `/CMS/App_Data/DBSeparation/procedures_functions_views.txt`. 39 | 1. Run `2-Remove-View.sql`, if necessary updating the query with the contents of `/CMS/App_Data/DBSeparation/procedures_functions_views.txt`. 40 | 1. Run `3-Remove-OM-Foreign-Keys.sql`, if necessary updating the query with the contents of `/CMS/App_Data/DBSeparation/temporary_tables.txt`. 41 | 1. Run `4-Remove-Other-Foreign-Keys.sql` 42 | 1. Run `5-Remove-Tables.sql` (**multiple times till all tables gone**), if necessary updating the query with the contents of `/CMS/App_Data/DBSeparation/tables.txt`. 43 | 1. Run `6-Remove-Functions.sql`, if necessary updating the query with the contents of `/CMS/App_Data/DBSeparation/procedures_functions_views.txt`. 44 | 1. Run `7-Remove-Table-Types.sql`, if necessary updating the query with the contents of `/CMS/App_Data/DBSeparation/copy_types.txt`. 45 | 46 | At this point, your copied OM database is ready to be pointed to. These values will probably be done through CI/CD: 47 | 48 | 1. Add to your Admin solution the connection string `` 49 | 1. Add to your MVC Solution the connection string with the same name 50 | - .Net Core, in `appsettings.json`, under the `ConnectionStrings` object, add `"CMSOMConnectionString": ""` 51 | - MVC 5 in your web.config's connection string add `` 52 | 1. Deploy your sites 53 | 54 | ### Minimize data loss 55 | 56 | As noted, from the time you clone the database to the time you push up the `CMSOmConnectionString` connection string to your site/admin, any OM related data will be lost. 57 | 58 | It is recommended that you prepare your CI/CD to deploy with the new connection strings, or possibly be ready to update and add the `CMSOmConnectionString` keys manually as soon as the procedure is complete. 59 | 60 | ## Clean up of Main Database 61 | 62 | At this point, you can safetly clean up your main database. It doesn't hurt anything to keep the OM tables in your main Database (although if you do, you should clear the data out), however it's recommended you remove them as any modifications to the table structures will only go to the separated database and may cause confusion. 63 | 64 | 1. Backup your MAIN Database (Don't be that guy...) 65 | 1. On the Main Database... 66 | 1. Run `Cleanup-1-Remove-OM-Tables.sql`, if necessary updating the query with the contents of `/CMS/App_Data/DBSeparation/tables.txt` **IN INVERSE ORDER** 67 | 1. Run `Cleanup-2-Remove-OM-Functions.sql`, if necessary updating the query with the contents of `/CMS/App_Data/DBSeparation/procedures_functions_views.txt` **IN INVERSE ORDER** 68 | 1. Run `Cleanup-3-Remove-OM-Views.sql`, if necessary updating the query with the contents of `/CMS/App_Data/DBSeparation/procedures_functions_views.txt` **IN INVERSE ORDER** 69 | 1. Run `Cleanup-4-Remove-OM-Stored-Procedures.sql`, if necessary updating the query with the contents of `/CMS/App_Data/DBSeparation/procedures_functions_views.txt` **IN INVERSE ORDER** 70 | 71 | Your OM related tables are now removed from your main database. 72 | 73 | ## Optional Linking or Cross Query Setup 74 | 75 | If your database supports Linked Servers and exists on the same server, and you wish to set up Linked Servers, you can run the `/CMS/App_Data/DBSeparation/linked_server.txt` on your **OM Separated Database**, replacing... 76 | 77 | - `##BASESERVER##` with the server name of your main database 78 | - `##BASEDATABASENAME##` with the database name of your main database 79 | - `##BASEUSERNAME##` with the main database username 80 | - `##BASEUSERPASS##` with the main database password 81 | 82 | If you're on Azure and you want to utilize Elastic Queries (cross-database querying), see the bottom of [Kentico's documentation](https://docs.xperience.io/on-line-marketing-features/configuring-and-customizing-your-on-line-marketing-features/separating-the-contact-management-database) where it describes how to enable this feature. 83 | 84 | ## Final Notes 85 | 86 | This was run on Kentico Xperience 13 hotfix 115, if the tables, foreign keys, or other related items are different in your hotfix of Kentico Xperience 13, please make sure to check the various `/CMS/App_Data/DBSeparation` text files and update the SQL files accordingly. 87 | 88 | I am not responsible for any issues using this procedure may result in. Please be sure to test this operation on a development copy of the site/database, and always be ready to roll back. -------------------------------------------------------------------------------- /src/KX13/SetPageTemplatesOnMissingNodes.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------- 2 | ---- Set Page Templates on Pages --------------------- 3 | ------------------------------------------------------- 4 | ---- If a page was not created when page templates ---- 5 | ---- were available, you can use this to force set ---- 6 | ---- the page template in the DB. You will need to---- 7 | ---- manually push pages if you have staging ---- 8 | ---- enabled, as well as publish any pages in edit ---- 9 | ---- mode. ---- 10 | ------------------------------------------------------- 11 | ---- ALWAYS BACK UP BEFORE RUNNING ---- 12 | ------------------------------------------------------- 13 | 14 | declare @PageType nvarchar(100) = 'custom.mypage' 15 | declare @TemplateIdentifier nvarchar(100) = 'custom.mypage_default' 16 | declare @TemplatePropertiesJsonObj nvarchar(max) = 'null' 17 | declare @TemplatePropertiesJsonObjXmlEncoded nvarchar(max) = 'null' 18 | 19 | -- Updates version history for the checked out version. This doesn't impact the published version however. 20 | update CMS_VersionHistory set NodeXML = REPLACE(NodeXML, '', '{"identifier":"'+@TemplateIdentifier+'","properties":'+@TemplatePropertiesJsonObjXmlEncoded+'}') 21 | where VersionHistoryID in ( 22 | Select DocumentCheckedOutVersionHistoryID from View_CMS_Tree_Joined where ClassName = @PageType and DocumentPageTemplateConfiguration is null 23 | ) and CHARINDEX('DocumentPageTemplateConfiguration', NODEXML) <= 0 24 | 25 | -- Sets the main table value as well 26 | update D set D.DocumentPageTemplateConfiguration = '{"identifier":"'+@TemplateIdentifier+'","properties":'+@TemplatePropertiesJsonObj+'}' from CMS_Document D 27 | left join CMS_Tree T on T.NOdeID = D.DocumentNOdeID 28 | Left join CMS_Class C on C.CLassID = T.NodeCLassID where ClassName = @PageType and DocumentPageTemplateConfiguration is null -------------------------------------------------------------------------------- /src/KX9-10-Upgrade/PREUPGRADE-0-Truncate-Ecommerce-Phones.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------------------------------- 2 | -------- PRE UPGRADE Kentico 9 to Kentico 10 ------------ 3 | -------- Ecommerce Address Fix ------------ 4 | -- Instances of Kentico Xperience that started before Kentico 10 may have -- 5 | -- foreign key dependencies that will cause sql errors during upgrade. This -- 6 | -- script should be ran just prior to running the upgrade script to foreign -- 7 | -- key dependencies. -- 8 | -- -- 9 | -- ALWAYS Backup before running these. Don't be THAT Guy -- 10 | -- Author: Trevor Fayas, version 1.0.0 -- 11 | ------------------------------------------------------------------------------- 12 | 13 | UPDATE COM_Customer set CustomerPhone = LEFT(CustomerPhone, 26) where Len(COALESCE(CustomerPhone, '')) > 26 14 | UPDATE COM_OrderAddress set AddressPhone = LEFT(AddressPhone, 26) where Len(COALESCE(AddressPhone, '')) > 26 15 | UPDATE COM_Address set AddressPhone = LEFT(AddressPhone, 26) where Len(COALESCE(AddressPhone, '')) > 26 16 | ALTER TABLE COM_Customer ALTER COLUMN CustomerPhone nvarchar(26) NULL 17 | ALTER TABLE COM_OrderAddress ALTER COLUMN [AddressPhone] nvarchar(26) NULL 18 | ALTER TABLE COM_Address ALTER COLUMN [AddressPhone] nvarchar(26) NULL --------------------------------------------------------------------------------