sh-notion/notion_data_team_no_files/Migration Old Dash → New Dash impacts upon DWH 1ae0446ff9c9800eb0e6d02722031254.md
Pablo Martin a256b48b01 pages
2025-07-11 16:15:17 +02:00

8.4 KiB
Raw Blame History

Migration Old Dash → New Dash impacts upon DWH

Whenever an Old Dash account needs to be migrated to the New Dash, the following script is run on live:

  • [MigrateUserToNewDash].sql

    /****** Object:  StoredProcedure [dbo].[MigrateUserToNewDash]    Script Date: 06/03/2025 13:10:13 ******/
    SET ANSI_NULLS ON
    GO
    SET QUOTED_IDENTIFIER ON
    GO
    ALTER   PROCEDURE [dbo].[MigrateUserToNewDash]
        @userId varchar(50)
    AS
    BEGIN
    
    	SET NOCOUNT ON
    
        IF @userId IS NULL
        BEGIN
            SELECT 0 AS Success, 'UserId cannot be null' AS ProblemMessage, 'MigrateUserToNewDash has not received a userId' AS ErrorMessage;
            RETURN
        END
    
        IF NOT EXISTS (SELECT 1 FROM dbo.Claim WHERE UserId = @userId AND ClaimType = 'Platform')
        BEGIN
            SELECT 0 AS Success, 'User does not have Platform ClaimType' AS ProblemMessage, 'MigrateUserToNewDash stored procedure requires a user with Platform ClaimType' AS ErrorMessage;
            RETURN
        END
    
    	BEGIN TRY
    
    		SET @userId = LOWER(@userId)
            DECLARE @date datetime = GETUTCDATE()
            DECLARE @platformRoleId UNIQUEIDENTIFIER
    		DECLARE @knowYourGuestRoleId UNIQUEIDENTIFIER
    		DECLARE @newDashVersion varchar(100)
    		DECLARE @pmsName varchar(200) = 'Unknown'
    
            SET @platformRoleId = (SELECT Id FROM [Role] WHERE [Name] = 'Platform')
            SET @knowYourGuestRoleId = (SELECT Id FROM [Role] WHERE [Name] = 'KnowYourGuest')
            SET @newDashVersion = (SELECT AppSettingValue FROM dbo.AppSetting WHERE AppSettingKey = 'KygVersionForDataTeam')
    		SET @pmsName = (SELECT TOP 1 it.[Name] FROM integration.Integration i INNER JOIN integration.IntegrationType it ON i.IntegrationTypeId = it.Id WHERE SuperhogUserId = @userId and IsActive = 1 ORDER BY i.Id Desc)
    
            DECLARE @accommodationIdsOfInterest TABLE(AccommodationId int)
            DECLARE @bookingIdsOfInterest TABLE(BookingId int)
            DECLARE @bookingViewIdsOfInterest Table (BookingViewId int)
    		DECLARE @verificationRequestIdsOfInterest TABLE(VerificationRequestId int)
    
            INSERT INTO @accommodationIdsOfInterest 
    		SELECT AccommodationId FROM AccommodationToUser WHERE SuperhogUserId = @userId
    
            INSERT Into @bookingIdsOfInterest
            SELECT 
    			BookingId 
            FROM 
    			Booking b
            INNER JOIN 
    			@accommodationIdsOfInterest a ON a.AccommodationId = b.AccommodationId
            WHERE 
    			NOT EXISTS (SELECT 1 FROM VerificationRequest WHERE Id = b.VerificationRequestId AND SuperhogUserId IS NOT NULL)
            AND 
    			IntegrationId IS NOT NULL
            AND 
    			CheckIn > @date
    		AND 
    			ISNULL(Summary, '') <> 'AIRBNB_CANCELLATION'
    
            INSERT INTO @bookingViewIdsOfInterest
            SELECT Id FROM BookingView bv INNER JOIN @bookingIdsOfInterest boi ON bv.BookingId = boi.BookingId
    
            INSERT INTO @verificationRequestIdsOfInterest
            SELECT 
    			Id 
    		FROM 
    			VerificationRequest
            WHERE 
    			Id IN (SELECT VerificationRequestId FROM Booking WHERE BookingId in (SELECT BookingId FROM @bookingIdsOfInterest))
    
    		BEGIN TRANSACTION
    
    			DELETE FROM dbo.Claim WHERE UserId = @userId and ClaimType = 'Platform'
                DELETE FROM dbo.UserRole WHERE UserId = @userId and RoleId = @platformRoleId
    
                IF @pmsName IS NOT NULL
                BEGIN
                    INSERT INTO dbo.Claim (UserId, ClaimType, ClaimValue)
                    VALUES (@userId, 'KygRegistrationIntegrationTypeName', @pmsName);
                END
    
                INSERT INTO dbo.Claim (UserId, ClaimType, ClaimValue)
                VALUES 
                    (@userId, 'KygRegistrationSignUpType', 'KygFreemium'),
                    (@userId, 'NewDashMoveDate', CONVERT(VARCHAR(200), @date, 120)),
                    (@userId, 'KygSource', 'olddashboard'),
    				(@userId, 'NewDashVersion', @newDashVersion);
    
                INSERT INTO dbo.UserRole (UserId, RoleId)
                VALUES (@userId, @knowYourGuestRoleId);
    
                INSERT INTO UserProductBundle([Name], DisplayName, DisplayOnFrontEnd, SuperhogUserId, ProductBundleId, StartDate, CreatedDate, UpdatedDate, ProtectionPlanId, ChosenProductServices)
                SELECT pb.[Name], pb.DisplayName, pb.DisplayOnFrontEnd, @userId, pb.Id, @date, @date, @date, pb.ProtectionPlanId, p.RequiredProductServices
                FROM ProductBundle pb
                INNER JOIN ProtectionPlan pp ON pb.ProtectionPlanId = pp.Id
                INNER JOIN Protection p ON p.Id = pp.ProtectionId
    			WHERE pp.EndDate IS NULL
    
                UPDATE Booking SET VerificationRequestId = NULL WHERE BookingId IN (SELECT BookingId FROM @bookingIdsOfInterest)
                UPDATE BookingView SET VerificationRequestId = NULL WHERE BookingId IN (SELECT BookingId FROM @bookingIdsOfInterest)
                UPDATE PricePlanToUser SET ListingFeeNet = 0 WHERE SuperhogUserId = @userId AND StartDate < @date AND ((EndDate > @date) OR (EndDate is null))
    
                DELETE FROM Verification WHERE VerificationRequestId IN (SELECT VerificationRequestId FROM @verificationRequestIdsOfInterest)
                DELETE FROM VerificationRequestFeatureFlag WHERE VerificationRequestId IN (SELECT VerificationRequestId FROM @verificationRequestIdsOfInterest)
                DELETE FROM VerificationRequest WHERE Id IN (SELECT VerificationRequestId FROM @verificationRequestIdsOfInterest)
    
                DELETE FROM integration.StayImportToBooking WHERE BookingId IN (SELECT BookingId FROM @bookingIdsOfInterest)
    			DELETE FROM BookingToProductBundle WHERE BookingId IN (SELECT BookingId FROM @bookingIdsOfInterest)
    			DELETE FROM ScreeningToBooking WHERE BookingId IN (SELECT BookingId FROM @bookingIdsOfInterest)
    
    			DELETE FROM BookingViewToService WHERE BookingViewId IN (SELECT BookingViewId FROM @bookingViewIdsOfInterest)
    			DELETE FROM BookingView WHERE Id IN (SELECT BookingViewId FROM @bookingViewIdsOfInterest)
    
    			DELETE FROM Booking WHERE BookingId IN (SELECT BookingId FROM @bookingIdsOfInterest)
    
                UPDATE Booking SET IsLegacy = 1 WHERE AccommodationId IN (SELECT AccommodationId FROM @accommodationIdsOfInterest)
    
            COMMIT TRANSACTION
    
    		SELECT 1 AS Success, NULL AS ProblemMessage, NULL AS ErrorMessage
    	END TRY  
    	BEGIN CATCH  
            IF @@TRANCOUNT > 0  
    		BEGIN
    
    			ROLLBACK TRANSACTION
    		END
    
    		DECLARE @ErrorMessage NVARCHAR(4000)
    
    		SET @ErrorMessage  = ERROR_MESSAGE()
    
    		SELECT 0 AS Success, 'Catch statement caught in MigrateUserToNewDash' AS ProblemMessage, ERROR_MESSAGE() AS ErrorMessage
    
    	 END CATCH  
    
    END
    
    

This has the following impacts:

Data Drift on DWH

  • UPDATE lines: these should also set the UpdatedDate so we can capture the change automatically in DWH. This refers to lines 102 (Booking), 103 (BookingView), 104 (PricePlanToUser) and 119 (Booking). Likely though Booking and BookingView records are deleted later so should not affect.
  • DELETE lines: this is troublesome on DWH side as it definitely creates drift, but setting a full-refresh on Data side for each affected table every day will be very expensive. Best would be to wait for Pablo being back as he's the expert. This affects lines 106 (Verification), 107 (VerificationRequestFeatureFlag), 108 (VerificationRequest), 111 (BookingToProductBundle), 117 (Booking)

Missing historical data

  • PricePlanToUser should also modify the minimum listing fee to 0, to my understanding - unless this is somehow needed for New Dash but I doubt it
  • I'd personally prefer enddating the latest record of the user and inserting a new one with the needed values at 0; so we keep historical data of price plans per user unaltered - unless this is somehow affecting the logic for New Dash

Worth mentioning that I dont observe impacts on DWH due to:

  • DELETE on Claim & UserRole does not affect us as we refresh the tables every day.
  • DELETE on lines 110 (StayImportToBooking) and 112 (ScreeningToBooking) does not affect us as we do not have these tables in DWH.

This problem is being handled here: https://guardhog.visualstudio.com/Data/_workitems/edit/28243