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 a list of items with serial numbers which were purchased and the linked sales transaction.
CREATE VIEW uv_AZRCRV_AllocatedSerialNumbers AS
/*
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
['Purchasing Receipt Line Quantities'].PONUMBER
,['Purchasing Receipt Line Quantities'].VENDORID
,['Purchasing Receipt Line Quantities'].POPRCTNM
,['Sales Serial/Lot Work and History'].ITEMNMBR
,[Purchasing Serial Lot History'].SERLTNUM
,['Sales Serial/Lot Work and History'].SOPTYPE
,CASE ['Sales Serial/Lot Work and History'].SOPTYPE
WHEN 1 THEN 'Quote'
WHEN 2 THEN 'Order'
WHEN 3 THEN 'Invoice'
WHEN 5 THEN 'Back Order'
ELSE ''
END AS 'Type'
,['Sales Serial/Lot Work and History'].SOPNUMBE
,['Sales Transactions'].DOCDATE
,['Sales Transactions'].DOCID
FROM
POP30330 AS [Purchasing Serial Lot History']
INNER JOIN
POP10500 AS ['Purchasing Receipt Line Quantities']
ON
['Purchasing Receipt Line Quantities'].POPRCTNM = [Purchasing Serial Lot History'].POPRCTNM
AND
['Purchasing Receipt Line Quantities'].RCPTLNNM = [Purchasing Serial Lot History'].RCPTLNNM
LEFT JOIN
SOP10201 AS ['Sales Serial/Lot Work and History']
ON
['Sales Serial/Lot Work and History'].SERLTNUM = [Purchasing Serial Lot History'].SERLTNUM
LEFT JOIN
(
SELECT
SOPNUMBE
,SOPTYPE
,DOCID
,DOCDATE
,CUSTNMBR
,CUSTNAME
FROM
SOP10100 AS ['Sales Transaction Work']
UNION ALL
SELECT
SOPNUMBE
,SOPTYPE
,DOCID
,DOCDATE
,CUSTNMBR
,CUSTNAME
FROM
SOP30200 AS ['Sales Transaction History']
) AS ['Sales Transactions']
ON
['Sales Transactions'].SOPNUMBE = ['Sales Serial/Lot Work and History'].SOPNUMBE
AND
['Sales Transactions'].SOPTYPE = ['Sales Serial/Lot Work and History'].SOPTYPE
GO
GRANT SELECT ON uv_AZRCRV_AllocatedSerialNumbers TO DYNGRP
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.