Transfer Old RM Statement Emails to New Email Fields

Microsoft Dynamics GPI’ve been involved with a recent upgrade of Microsoft Dynamics GP 10 to 2015. Two of the new features we helped introduce is the use of Word Templates and the Email Documents to replace the old statement email functionality which was dependent on Adobe Writer.

To help the client make the transition from the old to the new, I created an SQL script to transfer the email addresses from the table, RM00106 (RM Statement Emails) used by the old Adobe Writer to the SY01200 (Address Email Master) used by the Email Documents functionality.

This script picks up the To, Cc and Bcc email addresses and adds them to the appropriate field in the new table for the Statement Address and operates on the assumption that there are no email addresses already against this address.

The script also handles multiple email address of the same type (e.g. three To Email address for the same customer):

CREATE TABLE #RM00106(
	CUSTNMBR VARCHAR(100)
	,Email_Type INT
	,Email_Recipient VARCHAR(8000)
)
GO

INSERT INTO #RM00106
	(CUSTNMBR,Email_Type,Email_Recipient)

(SELECT DISTINCT CUSTNMBR,Email_Type,
	(SELECT LEFT(Email_Recipient, LEN(Email_Recipient) - 1)
	FROM (
		SELECT RTRIM(Email_Recipient) + '; '
		FROM RM00106 RM106I WHERE RM106I.CUSTNMBR = RM106.CUSTNMBR AND RM106I.Email_Type = RM106.Email_Type
		FOR XML PATH ('')
	  ) RM106I (Email_Recipient)

	)
FROM
	RM00106 RM106)
GO

INSERT INTO SY01200
    (Master_Type
    ,Master_ID
    ,ADRSCODE
    ,INETINFO
    ,EmailToAddress
    ,EmailCcAddress
    ,EmailBccAddress)

	(SELECT 
		'CUS'
		,RM101.CUSTNMBR
		,RM101.STADDRCD
		,''
		,RM106_1.Email_Recipient
		,RM106_2.Email_Recipient
		,RM106_3.Email_Recipient
	FROM
		RM00101 AS RM101
	INNER JOIN
		#RM00106 AS RM106_1
			ON RM101.CUSTNMBR = RM106_1.CUSTNMBR AND RM106_1.Email_Type = 1
	LEFT JOIN
		#RM00106 AS RM106_2
			ON RM101.CUSTNMBR = RM106_2.CUSTNMBR AND RM106_2.Email_Type = 2
	LEFT JOIN
		#RM00106 AS RM106_3
			ON RM101.CUSTNMBR = RM106_3.CUSTNMBR AND RM106_3.Email_Type = 3
	WHERE
		(SELECT
		   COUNT(SY12.Master_ID)
		FROM
		   SY01200 SY12
		WHERE
		   SY12.Master_ID = RM101.CUSTNMBR
		   AND SY12.ADRSCODE = RM101.STADDRCD) = 0)
GO

As always when running an SQL script, make sure you have a good SQL backup before running the script.

What should we write about next?

Your Name (required) -
Your Email (required) -

(Visited 350 times, 1 visits today)