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 returns details of items where the quantity on hand does not match the sum of the goods booked in and despatched.
/*
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).
*/
SELECT
RTRIM(['Inventory Transaction Amounts History'].ITEMNMBR) AS 'Item Number'
,['Item Master'].ITEMDESC AS 'Item Description'
,['Inventory Transaction Amounts History'].TRXLOCTN AS 'Location/Site'
,SUM(['Inventory Transaction Amounts History'].TRXQTY) AS 'Transaction Quantity'
,['Item Quantity Master'].QTYONHND AS 'Quantity On Hand'
,['Item Quantity Master'].ATYALLOC AS 'Quantity Allocated'
,CASE WHEN ['Item Quantity Master'].QTYONHND <> 0 THEN
['Item Quantity Master'].QTYONHND
ELSE
0
END AS 'Adjustment Quantity'
FROM
IV30300 AS ['Inventory Transaction Amounts History']
INNER JOIN
IV00101 AS ['Item Master']
ON
['Item Master'].ITEMNMBR = ['Inventory Transaction Amounts History'].ITEMNMBR
INNER JOIN
IV00102 AS ['Item Quantity Master']
ON
['Item Quantity Master'].ITEMNMBR = ['Inventory Transaction Amounts History'].ITEMNMBR
AND
['Item Quantity Master'].LOCNCODE = ['Inventory Transaction Amounts History'].TRXLOCTN
GROUP BY
['Inventory Transaction Amounts History'].ITEMNMBR
,['Item Master'].ITEMDESC
,['Inventory Transaction Amounts History'].TRXLOCTN
,['Item Quantity Master'].QTYONHND
,['Item Quantity Master'].ATYALLOC
HAVING
SUM(['Inventory Transaction Amounts History'].TRXQTY) <> ['Item Quantity Master'].QTYONHND
GO
Click to show/hide the SQL Scripts for Microsoft Dynamics GP Series Index
What should we write about next?
If there is a topic which fits the typical ones of this site, which you would like to see me write about, please use the form, below, to submit your idea.
Looking for support or consultancy with Microsoft Dynamics GP?
I no longer work with Microsoft Dynamics GP, but the last company I worked for was ISC Software in the UK; if you’re looking for support or consultancy services with Microsoft Dynamics GP you can contact them here.