Writing off stock from Qty In Service from Dynamics GP using SQL

I have 9,791 items with QTY in service >0 that I want to "adjust" out of stock.

All these items have been financially accounted for, written off over the years, the IV account manually cleared by journal each month. However the items have been left in stock (why we do this is for another day).

My challenge is to remove the items from stock so that I can then delete all the inventory master records for items as they are all historical items that have been discontinued for over 10 years and I'm sick of seeing them in reports and enquiries.

To do this

  • I need to firstly create a stock transfer document for all the items and qtys, including bins and serial numbers
  • I need create a stock adjustment for the same items bin qtys and serial numbers to adjust the items out of stock
  • I need to post a reversing journal to undo the effect on the already adjusted accounts

I really don’t like the idea of trying to write a GP macro to do this, it will take forever to run and is complicated by having to select serial numbers and bin numbers for each item.

I could go for programming solution using eConnect, but looking at it, I don’t think the business rules are that difficult and the problem is quite constrained so just building the transactions in SQL will do me. I feel confident I won’t screw anything up here.

I will show you the scripts I’ve used but be aware that I know this system well, you may have other modules installed that would affect things, or have GP set up in different ways that will cause issues. So TEST! TEST! TEST! first, I can take to responsibility for what happens on your system with this script!

To generate a transfer, create an empty inventory transfer with no lines, take a note of the document number and set it as the variable in the script. Save the GP document and come out of it.

Run the first half of the SQL script to create transfers for ALL the items in inventory that have a type of “In Service”. Obviously this could be narrowed down to your own needs with some more where clauses.

Note that I have made some safe assumptions for the dataset I’m working with, some of the field values are tied down rather than looked up. For example, you would need to check the account indexes for your inventory accounts before running the script, but it provides a starting point.

Once the SQL has generated the transfer, post it. Once posted run the second half of the SQL script, this will use the posted transfer to generate the inventory adjustment.

Now post the inventory adjustment.

Note: When I tried this it took over 19 hours on the test environment, after switching off the Intrastat Module it only took a few mins, see more on this at the bottom of this post. 

Finally in our case we needed some reversing journals to put the accounts back to where they should have been, but that was only as we were not using the system correctly in the first place!

The SQL…



DECLARE @IVDOCNMBR CHAR(17)

-- Create a new Inventory Transfer Document, Save it then enter its number here
-- this will be the document that will be loaded with items
SELECT @IVDOCNMBR = '00017213'

-- Load all items that have an "in service" value to a stock transfer to change to "on hand"
INSERT INTO IV10001
SELECT @IVDOCNMBR
,3
,IV00101.ITEMNMBR
,(
ROW_NUMBER() OVER (
ORDER BY IV00101.ITEMNMBR
) - 1
) * 16384 + 16384
,IV40201.BASEUOFM
,IV40202.QTYBSUOM
,IV00102.QTYINSVC
,CURRCOST
,STNDCOST * IV00102.QTYINSVC
,IV00102.LOCNCODE
,IV00102.LOCNCODE
,4
,1
,2011
,523
,0x00000000
,DECPLCUR
,IV00101.DECPLQTY
,0
,''
FROM IV00101
JOIN IV00102 ON IV00101.ITEMNMBR = IV00102.ITEMNMBR
AND IV00102.RCRDTYPE = 2
JOIN IV40201 ON IV40201.UOMSCHDL = IV00101.UOMSCHDL
JOIN IV40202 ON IV40202.UOMSCHDL = IV40201.UOMSCHDL
AND IV40202.UOFM = IV40201.BASEUOFM
WHERE QTYINSVC > 0

INSERT INTO IV10003
SELECT IVDOCNBR
,IVDOCTYP
,LNSEQNBR
,(
ROW_NUMBER() OVER (
ORDER BY IV10001.ITEMNMBR
) - 1
) * 16384 + 16384
,IV10001.ITEMNMBR
,TRXLOCTN
,IV00112.BIN
,IV00112.BIN
,TRFQTYTY
,IV00112.QUANTITY
,0
FROM IV10001
JOIN IV00112 ON IV10001.ITEMNMBR = IV00112.ITEMNMBR
AND IV10001.TRXLOCTN = IV00112.LOCNCODE
AND IV10001.TRFQTYTY = IV00112.QTYTYPE
WHERE IVDOCNBR = @IVDOCNMBR
AND IV00112.QUANTITY - IV00112.ATYALLOC > 0

INSERT INTO IV10002
SELECT IVDOCNBR
,IVDOCTYP
,IV10001.ITEMNMBR
,IV00200.SERLNMBR
,1
,IV10001.LNSEQNBR
,(
ROW_NUMBER() OVER (
ORDER BY IV10001.ITEMNMBR
) - 1
) * 16384 + 16384
,IV00200.DATERECD
,IV00200.DTSEQNUM
,0
,0
,IV00200.BIN
,IV00200.BIN
,'1900-01-01'
,'1900-01-01'
FROM IV10001
JOIN IV00200 ON IV10001.ITEMNMBR = IV00200.ITEMNMBR
AND IV10001.TRXLOCTN = IV00200.LOCNCODE
AND IV10001.TRFQTYTY = IV00200.QTYTYPE
WHERE IVDOCNBR = @IVDOCNMBR
AND IV00200.SERLNSLD = 0

UPDATE IV00200
SET SERLNSLD = 1
FROM IV10001
JOIN IV10002 ON IV10001.IVDOCNBR = IV10002.IVDOCNBR
AND IV10001.IVDOCTYP = IV10002.IVDOCTYP
AND IV10001.LNSEQNBR = IV10002.LNSEQNBR
JOIN IV00200 ON IV10002.ITEMNMBR = IV00200.ITEMNMBR
AND IV10001.TRXLOCTN = IV00200.LOCNCODE
AND IV10002.DATERECD = IV00200.DATERECD
AND IV10002.DTSEQNUM = IV00200.DTSEQNUM
AND IV10002.SERLTNUM = IV00200.SERLNMBR
AND IV10001.TRFQTYTY = IV00200.QTYTYPE
WHERE IV10002.IVDOCNBR = @IVDOCNMBR

-----------------------------------------------------------------------------------
-- Post the generated document, once sucessfully posted run the next part that follows
---- prepare the inventory adjustment by creating a new inventory adjustment and saving it (empty)
-- enter the previous document number for the stock transfer, and the empty adjustment number - an inventory adjustment
-- will be created from the transfer to adjust all that stock out.
DECLARE @IVDOCNMBR CHAR(17)

SELECT @IVDOCNMBR = '00017213' -- posted (in history) inventory transfer

DECLARE @IVDOCNMBR2 CHAR(17)

SELECT @IVDOCNMBR2 = '00054595' -- empty inventory adjustment

INSERT INTO IV10001
SELECT @IVDOCNMBR2
,1
,IV30300.ITEMNMBR
,(
ROW_NUMBER() OVER (
ORDER BY IV30300.ITEMNMBR
) - 1
) * 16384 + 16384
,IV30300.UOFM
,IV30300.QTYBSUOM
,- 1 * TRXQTY
,UNITCOST
,0
,IV30300.TRNSTLOC
,''
,0
,0
,525
,2008
,0x00000000
,DECPLCUR
,IV30300.DECPLQTY
,0
,''
FROM IV30300
WHERE IV30300.DOCNUMBR = @IVDOCNMBR
AND IV30300.DOCTYPE = 3

INSERT INTO IV10003
SELECT @IVDOCNMBR2
,1
,IV30300.LNSEQNBR
,IV30302.SEQNUMBR
,IV30302.ITEMNMBR
,IV30302.LOCNCODE
,TOBIN
,''
,IV30302.QTYTYPE
,IV30302.QTYSLCTD
,0
FROM IV30302
JOIN IV30300 ON IV30302.DOCNUMBR = IV30300.DOCNUMBR
AND IV30302.DOCTYPE = IV30300.DOCTYPE
AND IV30302.LNSEQNBR = IV30300.LNSEQNBR
WHERE IV30300.DOCNUMBR = @IVDOCNMBR

INSERT INTO IV10002
SELECT @IVDOCNMBR2
,1
,IV30400.ITEMNMBR
,[SERLTNUM]
,1
,LNSEQNBR
,SLTSQNUM
,DATERECD
,DTSEQNUM
,0
,0
,TOBIN
,''
,'1900-01-01'
,'1900-01-01'
FROM [IV30400]
JOIN IV00200 ON IV30400.ITEMNMBR = IV00200.ITEMNMBR
AND IV30400.SERLTNUM = IV00200.SERLNMBR
AND IV00200.SERLNSLD = 0
WHERE DOCNUMBR = @IVDOCNMBR

UPDATE IV00200
SET SERLNSLD = 1
FROM IV10001
JOIN IV10002 ON IV10001.IVDOCNBR = IV10002.IVDOCNBR
AND IV10001.IVDOCTYP = IV10002.IVDOCTYP
AND IV10001.LNSEQNBR = IV10002.LNSEQNBR
JOIN IV00200 ON IV10002.ITEMNMBR = IV00200.ITEMNMBR
AND IV10001.TRXLOCTN = IV00200.LOCNCODE
AND IV10002.DATERECD = IV00200.DATERECD
AND IV10002.DTSEQNUM = IV00200.DTSEQNUM
AND IV10002.SERLTNUM = IV00200.SERLNMBR
AND IV00200.QTYTYPE = 1
WHERE IV10002.IVDOCNBR = @IVDOCNMBR

ROLLBACK TRANSACTION

UPDATE IV00102
SET ATYALLOC = ATYALLOC + ABS(TRXQTY)
--SELECT *
FROM IV10001
JOIN IV00102 ON IV10001.ITEMNMBR = IV00102.ITEMNMBR
AND IV10001.TRXLOCTN = IV00102.LOCNCODE
AND TRFQTYTY = 0
WHERE IV10001.IVDOCNBR = @IVDOCNMBR2
AND IV10001.IVDOCTYP = 1

UPDATE IV00102
SET ATYALLOC = ATYALLOC + ABS(TRXQTY)
--SELECT *
FROM IV10001
JOIN IV00102 ON IV10001.ITEMNMBR = IV00102.ITEMNMBR
AND RCRDTYPE = 1
AND TRFQTYTY = 0
WHERE IV10001.IVDOCNBR = @IVDOCNMBR2
AND IV10001.IVDOCTYP = 1

 

Dynamics GP Intrastat module and slow posting of inventory transfer

 
When posting this large 3,000 line transaction with the Intrastat module switched on, it was still posting 18hrs later, at that point I killed the GP client process.
Looking at the SQL trace for what the GP client was doing before I killed it, it seemed to be that GP was iterating through each line of the transaction looking up something in the Intrastat VAT table but for every other line of the transaction too. You could see the occasional call to IV00101 where by the item number was moving to the next number, but then it would sit for ages calling out to the VAT tables for all the items on the order before moving on again.
 
intrastat iv posting sql trace showing calls to ZDP_VAT stored proc
 
After disabling the Intrastat module, the transaction posted in a few minutes, so there is some interaction with that module causing a serious degradation in performance on our system. In one of my previous posts I mentioned that the Intrastat module also causes the Sales order processing auto suggestion functionality to not work. I am now looking to see if we can report Intrastat without the need for the module so that ultimately I can switch it off for good.
 
 
 
 

Uppercase SQL script using SSMS

I just realised I use this functionality a lot and thought that others might not know it was possible.

Highlight a lower case bit of text in the SQL editor window of SSMS and press CTRL+SHIFT+U and the text will go to upper case (L for lower case).

SQL Upper case

This is handy when someone else has written a SQL script with GP field names in lower case as I’m so used to them in upper, it speeds up my reading to make them upper.

This is just an example. You may also highlight the whole script and make it upper case or individual lines, the above GIF is just showing the principle. In this particular case it would be quicker to have made the whole lot upper case then go back and lower case the table aliases.

Using SQL UNPIVOT operator to reconcile Dynamics GP inventory items

Working with the Dynamics GP inventory tables you will encounter the field named QTYTYPE a lot. This is usually seen with its partner LOCNCODE.

Inventory in GP can reside in different locations (for example depots New York, London, Sidney). That location then is broken down further into five item types. Item types can be though of condition/state of the item where the item states are an indexed as followed:

1 = On Hand
2 = Returned
3 = In Use
4 = In Service
5 = Damaged

This is a way we can categorise where and what state/status the inventory is in.

The item stock levels for each item is stored in the table IV00102, keyed by ITEMNMBR and LOCNCODE. To avoid creating four times more rows, the table architect decided to pivot the table, giving each quantity type its own field column in the table. The fields names are as follows:

ITEMTYPE Field Name Description
1 QTYONHND On Hand
2 QTYRTRND Returned
3 QTYINUSE In Use
4 QTYINSVC In Service
5 QTYDMGED Damaged

 

This presents a problem as the other inventory tables have a QTYTYPE field and have separate rows for different quantity types. If we need to join to the IV00102 table this becomes troublesome for us. One solution (I know there are others) is to use the UNPIVOT operator in TSQL to unpivot the IV00102 table, causing the columns to present themselves as extra rows.

SELECT ITEMNMBR
,LOCNCODE
,CASE valuename
WHEN 'QTYONHND'
THEN 1
WHEN 'QTYRTRND'
THEN 2
WHEN 'QTYINUSE'
THEN 3
WHEN 'QTYINSVC'
THEN 4
WHEN 'QTYDMGED'
THEN 5
END AS QTYTYPE
,QtyValue
FROM iv00102
UNPIVOT(QtyValue FOR valuename IN (
QTYONHND
,QTYRTRND
,QTYINUSE
,QTYINSVC
,QTYDMGED
)) UnPiv
WHERE ITEMNMBR = '100XLG'

This gives rise to the following result set.

SQL results

See how each quantity type now has its own row rather  than being named columns? We also used a CASE statement to alias the names of the columns back to index numbers.

Example, reconciling inventory values using SQL

In the blog post by Mahmood M. Alsaadi  Reconciling Quantity on Hand – SQL Script, he shows a script to reconcile inventory, so let us not reinvent the wheel and start with that script. The example provided in his post, at the time of writing did not take into account the quantity types. Unfortunately I ended up debugging the SQL to work this out, only to then return to the original post comments to find someone else had also done the same and pointed this out. However the solution they proposed was to tie the QTYTYPE=1 so that only on hand quantities are reconciled.  I felt I could do better than!

I build on the original script adding in the UNPIVOT introduced above:

SELECT TRX_BALANCE.ITEMNMBR AS ItemNumber
,TRXLOCTN AS Location
,Master_Balance.QTYTYPE AS QTYTYPE
,BALANCE AS TRX_BALNACE
,QtyValue AS Master_Balance
,ATYALLOC AS Master_AllocatedQuantity
,QtyAvailable
,BALANCE - QtyValue AS Variance
FROM (
SELECT ITEMNMBR
,TRXLOCTN
,QTYTYPE
,SUM(QTYRECVD) - SUM(QTYSOLD) AS BALANCE
FROM dbo.IV10200
--WHERE IV10200.ITEMNMBR='40-322'
GROUP BY ITEMNMBR
,TRXLOCTN
,QTYTYPE
) AS TRX_BALANCE
LEFT OUTER JOIN (
SELECT ITEMNMBR
,LOCNCODE
,CASE valuename
WHEN 'QTYONHND'
THEN 1
WHEN 'QTYRTRND'
THEN 2
WHEN 'QTYINUSE'
THEN 3
WHEN 'QTYINSVC'
THEN 4
WHEN 'QTYDMGED'
THEN 5
END AS QTYTYPE
,QtyValue
,CASE valuename
WHEN 'QTYONHND'
THEN ATYALLOC
ELSE 0
END AS ATYALLOC
,CASE valuename
WHEN 'QTYONHND'
THEN QtyValue - ATYALLOC
ELSE 0
END AS QtyAvailable
FROM IV00102
UNPIVOT(QtyValue FOR valuename IN (
QTYONHND
,QTYRTRND
,QTYINUSE
,QTYINSVC
,QTYDMGED
)) IV00102Pivot
) AS Master_Balance ON TRX_BALANCE.ITEMNMBR = Master_Balance.ITEMNMBR
AND TRX_BALANCE.TRXLOCTN = Master_Balance.LOCNCODE
AND TRX_BALANCE.QTYTYPE = Master_Balance.QTYTYPE
WHERE BALANCE - QtyValue <> 0

This will output the item, location and quantity type of the items that have an incorrect inventory level in the IV00102 table (this is the table viewed when looking at the Dynamics GP item enquiry form).

This can be a useful  script to set as a scheduled SQL Job to notify your GP admin that inventory needs reconciling, even listing the items that need reconciling. This could also lead to generation of a macro to do the reconcile… one for another day…..

Inventory Year End, Remove Sold Receipts and Cost Change History

Inventory year end closing window

FIFO has to be maintained somewhere so goods receipts are added to table IV10200, as the inventory is consumed the QTYSOLD field is incremented against the receipt, until the QTYRECVD = QTYSOLD and at this point the field RCPTSOLD is set from 0 to 1, to indicate that the receipt has been totally consumed. The order of receipts is chosen depending on the cost model, FIFO etc.

As can be seen above, as part of the year end closing, the option is provided to remove any consumed receipts before a specified date. If this option is chosen, then GP will look for receipts with RCPTSOLD=1 and DATERECD<{Date Provided}  and remove them from the IV10200 table. It will also remove the records in IV10201 that represent the demand against the receipt. You can see this if you run a SQL trace while it runs.

DELETE FROM IV10201 WHERE ITEMNMBR = 'myitem' AND SRCRCTSEQNM = 1 
 
I was worrying if this would affect the stock levels if I reconciled the inventory after removing the receipts. If you look at my other post Using SQL UNPIVOT operator to reconcile Dynamics GP inventory items then you will note that inventory reconcile calculates the available stock from the IV10200 table using:
SUM(QTYRECVD) - SUM(QTYSOLD)
As we are only removing rows where these are equal (as the whole receipt is sold), then they are rows that were not participating in the stock quantity anyway, hence no effect on stock reconciles.

In the above script SRCRCTSEQNM=1 (Source Receipt Sequence Number) is from the RCTSEQNM (Receipt Sequence Number) of the record removed from IV10200 binding demand and source. – or so it looks at first sight.
 
hey wait…
 
The key for receipts table IV10200 allows the same item to have the same shared RCTSEQNM if the dates received is different. Indeed our data has this a lot of the time, see the table screen shot for an item below, see how the item has multiple RCTSEQNM=1. I don’t think this should happen.
 
rectable
 
I had a look an our test copy of the live company, ran the above year end routine and indeed it removed all records from IV10201 for the sequence number, even though I think they related to records still remaining in IV10200! I’ve seen some posts regarding people finding missing data in their systems but not being able to track down why and what makes it happen, I think perhaps this may be an answer? It may be that I am interpreting what I am seeing wrong too, I need more information on how records relate.
 
Further investigation…
I don’t think I’m wrong, I have the feeling that we have some serious corruption in our table! After running the remove sold receipts then reconciling one of the items affected gives us this result:
 
itemreconcile
 
GP has added a record back into IV10201 to replace the one that was taken by the year end utility, I think this is a good indication that this is not supposed to have happened.
GP creates a new record in IV10201 with ORIGINDOCID field set to “RECON” (reconcile) for the full amount sold on the receipt, as it can’t now find the transaction details, as they were removed by the year end utility.
 
I’m guessing that the RCTSEQNM should auto increment for each receipt and that there should not duplicate RCTSEQNM for any item. The following script checks for instances of this happening in correctly.
 
SELECT 
ITEMNMBR,
RCTSEQNM,
COUNT(*) ,MAX(DATERECD)
FROM IV10200
GROUP BY ITEMNMBR, RCTSEQNM
HAVING COUNT(RCTSEQNM)>1
ORDER BY 4
(19498 row(s) affected)
Oh crickey! - there are 19498 item sequence number combinations where this has occurred. Looking at the first part of the result set we see this is real bad, some of the sequence numbers have been used 735 times, and that is just at first glance, I would rather not dig deeper. With the dates added, I see that this happened between years 1998 and 2009. I guess whatever the cause was went away after that year. So these days it does work how I would expect and the records are tied between the 200 and 201 tables by the RCTSEQNM (when the data is correct).
 
corruptseq
 
 
corruptseqdate
 
 
Where do I go from here?
So I need to clean up this mess, it looks like it may not be possible to recover from this and preserve data. As it happens I want to trim these receipts back to seven years anyway, so if I do that the problem will solve itself, I think. An item reconcile after the trim will rebuild dummy records for sold quantities if any are missing, so we end up in a better place than I am now.
 
 
It is not a good idea to delete a receipt and associated detail if consumed recently as it makes processing returns more difficult once a receipt has been removed.
 
If you don’t want to run year end for inventory, that updates starting qtys and summaries, you could try writing a SQL script to remove the records. This is something I've ended up doing, archiving the records in case I ever need them again too.
Here is the script I used, beware -this is only here as an example. You NEED to check this with your test environment first and be very careful about using it. I cannot fully guarantee this will be safe to run for your GP installation.
 
BEGIN TRANSACTION

DECLARE @DateThreshold DATETIME

SELECT @DateThreshold = '20091101'

DECLARE @ToRemove AS TABLE (
DATERECD DATETIME
,ITEMNMBR CHAR(31)
,TRXLOCTN CHAR(11)
,RCTSEQNM INT
,QTYTYPE SMALLINT
);

INSERT INTO @ToRemove (
DATERECD
,ITEMNMBR
,TRXLOCTN
,RCTSEQNM
,QTYTYPE
)
SELECT DISTINCT rcpt.DATERECD
,rcpt.ITEMNMBR
,rcpt.TRXLOCTN
,rcpt.RCTSEQNM
,rcpt.QTYTYPE
FROM IV10200 rcpt
WHERE rcpt.RCPTSOLD = 1
AND (rcpt.DATERECD < @DateThreshold)

--AND rcpt.ITEMNMBR='01-214'
DELETE IV10200
OUTPUT DELETED.[ITEMNMBR]
,DELETED.[TRXLOCTN]
,DELETED.[DATERECD]
,DELETED.[RCTSEQNM]
,DELETED.[RCPTSOLD]
,DELETED.[QTYRECVD]
,DELETED.[QTYSOLD]
,DELETED.[QTYCOMTD]
,DELETED.[QTYRESERVED]
,DELETED.[FLRPLNDT]
,DELETED.[PCHSRCTY]
,DELETED.[RCPTNMBR]
,DELETED.[VENDORID]
,DELETED.[PORDNMBR]
,DELETED.[UNITCOST]
,DELETED.[QTYTYPE]
,DELETED.[Landed_Cost]
,DELETED.[NEGQTYSOPINV]
,DELETED.[VCTNMTHD]
,DELETED.[ADJUNITCOST]
,DELETED.[QTYONHND]
INTO CANFDARCHIVE..IV10200
FROM IV10200
JOIN @ToRemove r ON IV10200.DATERECD = r.DATERECD
AND IV10200.ITEMNMBR = r.ITEMNMBR
AND IV10200.RCTSEQNM = r.RCTSEQNM
AND IV10200.TRXLOCTN = r.TRXLOCTN
AND IV10200.QTYTYPE = r.QTYTYPE
WHERE RCPTSOLD = 1
AND (IV10200.DATERECD < @DateThreshold)

--Remove orphan records
DELETE ld
OUTPUT DELETED.[ITEMNMBR]
,DELETED.[TRXLOCTN]
,DELETED.[QTYTYPE]
,DELETED.[DOCDATE]
,DELETED.[RCTSEQNM]
,DELETED.[ORIGINDOCTYPE]
,DELETED.[ORIGINDOCID]
,DELETED.[LNSEQNBR]
,DELETED.[CMPNTSEQ]
,DELETED.[QTYSOLD]
,DELETED.[UNITCOST]
,DELETED.[IVIVINDX]
,DELETED.[IVIVOFIX]
,DELETED.[SRCRCTSEQNM]
,DELETED.[TRXREFERENCE]
,DELETED.[PCHSRCTY]
INTO CANFDArchive.[dbo].[IV10201]
FROM IV10201 ld
LEFT JOIN IV10200 h
ON h.ITEMNMBR=ld.ITEMNMBR
AND h.TRXLOCTN=ld.TRXLOCTN
AND h.RCTSEQNM = ld.SRCRCTSEQNM
AND h.QTYTYPE=ld.QTYTYPE
WHERE h.DATERECD is null




COMMIT TRANSACTION