This script is part of the SQL Scripts for Microsoft Dynamics GP where I will be posted the scripts I wrote against Microsoft Dynamics GP over the 19 years before I stopped working with Dynamics GP.
This script ppdates the accounts and distributions on work status sales transactions from Item Master (IV00101), Sales/Purchases Tax Master (TX00201) or Posting Account Master (SY01100) tables.
/*
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).
*/
-- SALES TRANSACTION LINE DISTRIBUTIONS (DETAIL)
UPDATE
['Sales Transaction Amounts Work']
SET
INVINDX = ['Inventory Item Master'].IVIVINDX
,CSLSINDX = ['Inventory Item Master'].IVCOGSIX
,SLSINDX = ['Inventory Item Master'].IVSLSIDX
,MKDNINDX = ['Inventory Item Master'].IVSLDSIX -- SALES DISCOUNTS AVAILABLE
,RTNSINDX = ['Inventory Item Master'].IVRETIDX
,INUSINDX = ['Inventory Item Master'].IVINUSIX
,INSRINDX = ['Inventory Item Master'].IVINSVIX
,DMGDINDX = ['Inventory Item Master'].IVDMGIDX
FROM
SOP10200 AS ['Sales Transaction Amounts Work'] --Sales Transaction Amounts Work (SOP10200)
INNER JOIN
IV00101 AS ['Inventory Item Master'] --Item Master (IV00101)
ON
['Inventory Item Master'].ITEMNMBR = ['Sales Transaction Amounts Work'].ITEMNMBR
WHERE
['Sales Transaction Amounts Work'].SOPTYPE IN (1,2,4) -- quote/order/return
GO
-- SALES TRANSACTION TAX DISTRIBUTIONS
UPDATE
['Sales Taxes Work and History']
SET
ACTINDX = ['Sales/Purchases Tax Master'].ACTINDX
FROM
SOP10105 AS ['Sales Taxes Work and History']--Sales Taxes Work and History (SOP10105)
INNER JOIN
TX00201 AS ['Sales/Purchases Tax Master'] --Sales/Purchases Tax Master (TX00201)
ON
['Sales/Purchases Tax Master'].TAXDTLID = ['Sales Taxes Work and History'].TAXDTLID
INNER JOIN
SOP10100 AS ['Sales Transaction Work'] --Posting Account Master (SY01100)
ON
['Sales Transaction Work'].SOPTYPE = ['Sales Taxes Work and History'].SOPTYPE
AND
['Sales Transaction Work'].SOPNUMBE = ['Sales Taxes Work and History'].SOPNUMBE
GO
--SALES TRANSACTION DISTRIBUTIONS (SUMMARY)
/*
1 --SALES
2 --RECV
6 --TRADE
7 --FREIGHT
9 --MISC
11 --COMMEXP
12 --COMMPAY
14 --COGS
15 --INV
16 --RETURN
17 --IN USE
18 --IN SERVICE
19 --DAMAGED
22 --ROUND
*/
--SALES
UPDATE
['Sales Distribution Work and History']
SET
ACTINDX = ['Posting Account Master'].ACTINDX
FROM
SOP10102 AS ['Sales Distribution Work and History'] --Sales Distribution Work and History (SOP10102)
INNER JOIN
SY01100 AS ['Posting Account Master'] --SY00110
ON
['Posting Account Master'].SERIES = 5
AND
['Posting Account Master'].PTGACDSC = 'Sales'
WHERE
['Sales Distribution Work and History'].DISTTYPE = 1
GO
--ACCOUNTS RECEIVABLE
UPDATE
['Sales Distribution Work and History']
SET
ACTINDX = ['Posting Account Master'].ACTINDX
FROM
SOP10102 AS ['Sales Distribution Work and History'] --Sales Distribution Work and History (SOP10102)
INNER JOIN
SY01100 AS ['Posting Account Master'] --Posting Account Master (SY01100)
ON
['Posting Account Master'].SERIES = 3
AND
['Posting Account Master'].PTGACDSC = 'Accounts Receivable'
WHERE
['Sales Distribution Work and History'].DISTTYPE = 2
GO
--TRADE DISCOUNT
UPDATE
['Sales Distribution Work and History']
SET
ACTINDX = ['Posting Account Master'].ACTINDX
FROM
SOP10102 AS ['Sales Distribution Work and History']
INNER JOIN
SY01100 AS ['Posting Account Master']
ON
['Posting Account Master'].SERIES = 3
AND
['Posting Account Master'].PTGACDSC = 'Trade Discount'
WHERE
['Sales Distribution Work and History'].DISTTYPE = 6
GO
--FREIGHT
UPDATE
['Sales Distribution Work and History']
SET
ACTINDX = ['Posting Account Master'].ACTINDX
FROM
SOP10102 AS ['Sales Distribution Work and History'] --Sales Distribution Work and History (SOP10102)
INNER JOIN
SY01100 AS ['Posting Account Master'] --Posting Account Master (SY01100)
ON
['Posting Account Master'].SERIES = 3
AND
['Posting Account Master'].PTGACDSC = 'Freight'
WHERE
['Sales Distribution Work and History'].DISTTYPE = 7
GO
--MISCELLANEOUS
UPDATE
['Sales Distribution Work and History']
SET
ACTINDX = ['Posting Account Master'].ACTINDX
FROM
SOP10102 AS ['Sales Distribution Work and History'] --Sales Distribution Work and History (SOP10102)
INNER JOIN
SY01100 AS ['Posting Account Master'] --Posting Account Master (SY01100)
ON
['Posting Account Master'].SERIES = 3
AND
['Posting Account Master'].PTGACDSC = 'Miscellaneous'
WHERE
['Sales Distribution Work and History'].DISTTYPE = 8
GO
--TAXES
UPDATE
['Sales Distribution Work and History']
SET
ACTINDX = ['Posting Account Master'].ACTINDX
FROM
SOP10102 AS ['Sales Distribution Work and History'] --Sales Distribution Work and History (SOP10102)
INNER JOIN
SY01100 AS ['Posting Account Master'] --Posting Account Master (SY01100)
ON
['Posting Account Master'].SERIES = 3
AND
['Posting Account Master'].PTGACDSC = 'Taxes'
WHERE
['Sales Distribution Work and History'].DISTTYPE = 9
GO
--COMMISSIONS EXPENSE
UPDATE
['Sales Distribution Work and History']
SET
ACTINDX = ['Posting Account Master'].ACTINDX
FROM
SOP10102 AS ['Sales Distribution Work and History'] --Sales Distribution Work and History (SOP10102)
INNER JOIN
SY01100 AS ['Posting Account Master'] --Posting Account Master (SY01100)
ON
['Posting Account Master'].SERIES = 3
AND
['Posting Account Master'].PTGACDSC = 'Commissions Expense'
WHERE
['Sales Distribution Work and History'].DISTTYPE = 11
GO
--COMMISSIONS PAYABLE
UPDATE
['Sales Distribution Work and History']
SET
ACTINDX = ['Posting Account Master'].ACTINDX
FROM
SOP10102 AS ['Sales Distribution Work and History'] --Sales Distribution Work and History (SOP10102)
INNER JOIN
SY01100 AS ['Posting Account Master'] --Posting Account Master (SY01100)
ON
['Posting Account Master'].SERIES = 3
AND
['Posting Account Master'].PTGACDSC = 'Commissions Payable'
WHERE
['Sales Distribution Work and History'].DISTTYPE = 12
GO
--COGS
UPDATE
['Sales Distribution Work and History']
SET
ACTINDX = ['Posting Account Master'].ACTINDX
FROM
SOP10102 AS ['Sales Distribution Work and History'] --Sales Distribution Work and History (SOP10102)
INNER JOIN
SY01100 AS ['Posting Account Master'] --Posting Account Master (SY01100)
ON
['Posting Account Master'].SERIES = 5
AND
['Posting Account Master'].PTGACDSC = 'Cost of Goods Sold'
WHERE
['Sales Distribution Work and History'].DISTTYPE = 14
GO
--INVENTORY
UPDATE
['Sales Distribution Work and History']
SET
ACTINDX = ['Posting Account Master'].ACTINDX
FROM
SOP10102 AS ['Sales Distribution Work and History'] --Sales Distribution Work and History (SOP10102)
INNER JOIN
SY01100 AS ['Posting Account Master'] --Posting Account Master (SY01100)
ON
['Posting Account Master'].SERIES = 5
AND
['Posting Account Master'].PTGACDSC = 'Inventory Control'
WHERE
['Sales Distribution Work and History'].DISTTYPE = 15
GO
--RETURNS
UPDATE
['Sales Distribution Work and History']
SET
ACTINDX = ['Posting Account Master'].ACTINDX
FROM
SOP10102 AS ['Sales Distribution Work and History'] --Sales Distribution Work and History (SOP10102)
INNER JOIN
SY01100 AS ['Posting Account Master'] --Posting Account Master (SY01100)
ON
['Posting Account Master'].SERIES = 5
AND
['Posting Account Master'].PTGACDSC = 'Sales Returns'
WHERE
['Sales Distribution Work and History'].DISTTYPE = 16
GO
--IN USE
UPDATE
['Sales Distribution Work and History']
SET
ACTINDX = ['Posting Account Master'].ACTINDX
FROM
SOP10102 AS ['Sales Distribution Work and History'] --Sales Distribution Work and History (SOP10102)
INNER JOIN
SY01100 AS ['Posting Account Master'] --Posting Account Master (SY01100)
ON
['Posting Account Master'].SERIES = 5
AND
['Posting Account Master'].PTGACDSC = 'In Use'
WHERE
['Sales Distribution Work and History'].DISTTYPE = 17
GO
--IN SERVICE
UPDATE
['Sales Distribution Work and History']
SET
ACTINDX = ['Posting Account Master'].ACTINDX
FROM
SOP10102 AS ['Sales Distribution Work and History'] --Sales Distribution Work and History (SOP10102)
INNER JOIN
SY01100 AS ['Posting Account Master'] --Posting Account Master (SY01100)
ON
['Posting Account Master'].SERIES = 5
AND
['Posting Account Master'].PTGACDSC = 'In Service'
WHERE
['Sales Distribution Work and History'].DISTTYPE = 18
GO
--DAMAGED
UPDATE
['Sales Distribution Work and History']
SET
ACTINDX = ['Posting Account Master'].ACTINDX
FROM
SOP10102 AS ['Sales Distribution Work and History'] --Sales Distribution Work and History (SOP10102)
INNER JOIN
SY01100 AS ['Posting Account Master'] --Posting Account Master (SY01100)
ON
['Posting Account Master'].SERIES = 5
AND
['Posting Account Master'].PTGACDSC = 'Damaged'
WHERE
['Sales Distribution Work and History'].DISTTYPE = 19
GO
--ROUNDING
UPDATE
['Sales Distribution Work and History']
SET
ACTINDX = ['Posting Account Master'].ACTINDX
FROM
SOP10102 AS ['Sales Distribution Work and History'] --Sales Distribution Work and History (SOP10102)
INNER JOIN
SY01100 AS ['Posting Account Master'] --Posting Account Master (SY01100)
ON
['Posting Account Master'].SERIES = 2
AND
['Posting Account Master'].PTGACDSC = 'Rounding Difference'
WHERE
['Sales Distribution Work and History'].DISTTYPE = 22
GO