Duplicate last exchange rate in Microsoft Dynamics GP for every day to future date

Microsoft Dynamics GPI’ve been involved in a project which has included a lot of development and therefore a lot of QA and UAT over a period of time. The client’s system is configured with daily exhcnage rates which has caused some issues with testing as not everyone doing testing has access to insert new rates.

To provide some consistency in the exchange rate for testing and to ensure that testing is not held up by missing exchange rates, I created the below SQL script to copy the last exchange rate and replicate forward for every day until a specific date (set in the highlighted parameter at the top); the rate tables which are updated are listed out qithin the query (second set of highlighted text).

This script was ***NOT*** created for use on a live system, which would include a test company on the live system, as the exchange rate tables are system setup data. It was created only for use on a standalone test system with no connection to live.

/*
Created by Ian Grieve of azurecurve | Ramblings of an IT Professional (http://www.azurecurve.co.uk) This code is licensed under the Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International (CC BY-NC-SA 4.0 Int). */
DECLARE @StartDate DATETIME = FORMAT(GETDATE(), 'yyyy-MM-dd') ,@EndDate DATETIME = '2020-12-31' ; WITH NewDatesToInsert AS ( SELECT @StartDate AS EXCHDATE UNION ALL SELECT DATEADD(day, 1, EXCHDATE) FROM NewDatesToInsert WHERE DATEADD(day, 1, EXCHDATE) <= @EndDate ) INSERT INTO MC00100 -- Multicurrency Exchange Rate Maintenance (MC00100) ( EXGTBLID,CURNCYID,EXCHDATE,TIME1,XCHGRATE,EXPNDATE ) --VALUES ( SELECT ['Multicurrency Exchange Table Dates To Insert'].EXGTBLID ,['Multicurrency Exchange Table Dates To Insert'].CURNCYID ,['Multicurrency Exchange Table Dates To Insert'].EXCHDATE ,'1900-01-01 00:00:00000' AS TIME1 ,ISNULL(( SELECT TOP 1 XCHGRATE FROM MC00100 WHERE EXGTBLID = ['Multicurrency Exchange Table Dates To Insert'].EXGTBLID ORDER BY EXCHDATE DESC ), 1) AS XCHGRATE ,DATEADD(day, 30, ['Multicurrency Exchange Table Dates To Insert'].EXCHDATE) AS EXPNDATE FROM ( SELECT ['Multicurrency Exchange Table Setup'].EXGTBLID ,['Multicurrency Exchange Table Setup'].CURNCYID ,['New Dates To Insert'].EXCHDATE FROM NewDatesToInsert AS ['New Dates To Insert'] CROSS JOIN MC40300 AS ['Multicurrency Exchange Table Setup'] -- Multicurrency Exchange Table Setup (MC40300) WHERE ['Multicurrency Exchange Table Setup'].EXGTBLID IN ('Z-UK-BUY','Z-UK-SELL','Z-UK-AVG') ) AS ['Multicurrency Exchange Table Dates To Insert'] INNER JOIN MC40200 AS [Currency Setup'] -- Currency Setup (MC40200) ON [Currency Setup'].CURNCYID = ['Multicurrency Exchange Table Dates To Insert'].CURNCYID WHERE ( SELECT COUNT(*) FROM MC00100 WHERE EXGTBLID = ['Multicurrency Exchange Table Dates To Insert'].EXGTBLID AND EXCHDATE = ['Multicurrency Exchange Table Dates To Insert'].EXCHDATE AND XCHGRATE IS NOT NULL ) = 0 ) OPTION (MAXRECURSION 0)