SQL Scripts for Microsoft Dynamics GP: PO Receipt History View

Microsoft Dynamics GPThis 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 creates a SQL view on the history of PO receipts including the purchase price variance.


CREATE VIEW uv_AZRCRV_POReceiptHistory 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 History'].LOCNCODE AS 'Site' ,['PM Creditor Master'].VENDNAME AS 'Vendor Name' ,['PM Creditor Master'].VENDORID AS 'Vendor ID' ,['Purchase Receipt History'].POPRCTNM AS 'Receipt Number' ,['Purchase Receipt History'].receiptdate AS 'Receipt Date' ,['Purchasing Receipt Line Quantities'].ITEMNMBR AS 'Item Number' ,['Purchasing Receipt Line Quantities'].PONUMBER as 'PO Number' ,['Purchasing Receipt Line Quantities'].QTYSHPPD AS 'Quantity Received' ,['Purchase Orders'].UNITCOST 'PO Unit Cost' ,['Item Master'].STNDCOST AS 'Standard Cost' ,['Item Master'].STNDCOST - ['Purchasing Receipt Line History'].UNITCOST AS 'Unrecognised PPV' ,['Purchasing Receipt Line Quantities'].QTYSHPPD * ['Purchase Orders'].UNITCOST AS 'Extended Cost' ,['Purchasing Receipt Line History'].ITEMDESC AS 'Item Description' ,['Item Master'].ITMCLSCD AS 'Item Class' ,['Purchasing Receipt Line History'].UOFM AS 'Unit of Measure' ,FORMAT( ['Purchase Receipt History'].receiptdate, 'MMM-yy' ) AS 'Month' ,FORMAT( ['Purchase Receipt History'].receiptdate, 'yyyy' ) AS 'Year' ,['Item Master'].ITMGEDSC AS 'Item Generic Description' FROM POP30300 AS ['Purchase Receipt History'] WITH (NOLOCK) --Purchasing Receipt History (POP30300) INNER JOIN POP30310 AS ['Purchasing Receipt Line History'] WITH (NOLOCK) --Purchasing Receipt Line History (POP30310) ON ['Purchasing Receipt Line History'].POPRCTNM = ['Purchase Receipt History'].POPRCTNM INNER JOIN IV00101 AS ['Item Master'] WITH (NOLOCK) --Item Master (IV00101) ON ['Item Master'].ITEMNMBR = ['Purchasing Receipt Line History'].ITEMNMBR INNER JOIN POP10500 AS ['Purchasing Receipt Line Quantities'] WITH (NOLOCK) --Purchasing Receipt Line Quantities (POP10500) ON ['Purchasing Receipt Line Quantities'].POPRCTNM = ['Purchasing Receipt Line History'].POPRCTNM AND ['Purchasing Receipt Line Quantities'].RCPTLNNM = ['Purchasing Receipt Line History'].RCPTLNNM INNER JOIN ( SELECT PONUMBER ,ORD ,UNITCOST FROM POP10110 WITH (NOLOCK) --Purchase Order Line (POP10110) UNION SELECT PONUMBER ,ORD ,UNITCOST FROM POP30110 WITH (NOLOCK) --Purchase Order Line History (POP30110) ) AS ['Purchase Orders'] ON ['Purchase Orders'].PONUMBER = ['Purchasing Receipt Line Quantities'].PONUMBER AND ['Purchase Orders'].ORD = ['Purchasing Receipt Line Quantities'].POLNENUM INNER JOIN PM00200 AS ['PM Creditor Master'] WITH (NOLOCK) --PM Vendor Master File (PM00200) ON ['PM Creditor Master'].VENDORID = ['Purchase Receipt History'].VENDORID WHERE ['Purchase Receipt History'].POPTYPE = 1 ORDER BY ['Purchase Receipt History'].POPRCTNM ,['Purchasing Receipt Line History'].RCPTLNNM GO

Click to show/hide the SQL Scripts for Microsoft Dynamics GP Series Index

SQL Scripts for Microsoft Dynamics GP
Verify PM Batches Exist
Update Accrued Purchases Distribution on History Receipts from Posting Account Setup
Insert Mfg BOMs from Text File
SQL Function To Return Approver
List of Active Fixed Assets
Insert Manufacturing Routings from Text File
Table Function to Split String on Delimiter
List of Open Payables Transactions
Insert Creditor Item Numbers
Return Top Level BOM for Manufacturing Orders
Custom Purchase Order Email Notification to Originator on Workflow Final Approval
list of Open Payables Distributions
Set New Vendor On Hold if EFT Exists
Set New Vendor On Hold if EFT Exists
Payment Run Apply Query
List GL Transactions
Simple RMA Audit
Change Vendor Change Approvals Joins and Fields
Insert National Accounts from CSV
List GL Accounts With Notes
Import Site Bins From CSV
Remove Multicurrency from Sales Transactions
Change Email Notification Assignment
List General Ledger Transactions (Excluding Year End Journals)
List Taxes Linked to GL Accounts
Allow Workflow Originator to be an Approver
Add Joins and Fields to PM Document Approval Notification Emails
Update Accounts and Distributions on Work Status Sales Transactions from Item Card, Tax Details or Posting Account Setup
Upload and Verify Tax Commodity Codes
Delete Corrupt Extended Pricing Data
Assign All Items to All Site Bins
Sales Transactions (Work) Against a Specific Site
Change Web Service URi
SQL View to Return Quantity Available
Verify Tax Detail Assigned to Vendor
Insert Extended Pricing Price Sheet Header
Prefix Companies Names with System Designator
SQL View to Return Category Linked to Segment 3 in COA
Update Site Descriptions From CSV
Copy Workflow from Source to Destination Database
Extract GL Period Balances
Sales by Customer By Year
Purchased Items With Serial Numbers and Linked Sales Transactions
SQL View to Return Purchase Orders
Select All Primary Keys and Generate ALTER Script
Copy Workflow Calendar from Source to Destination Database
SQL Trigger on PO invoice Insert to Change GL posted Date
Sales by Salesperson By Year
Script to Set Transactions as Included on VAT Daybook Return
SQL Script to Return PO Receipts
Insert Extended Pricing Price Sheet UofM Work
View for Payables Transactions Extract
Export Open/History PM Transactions After a Specified Date
Copy Email Messages from a Source to Destination Database
PO Receipt History View
Insert Extended Pricing Price Sheet Assignments
Extract Payables Transactions from All Companies
List Open Purchase Orders
SQL View to Create Division Tree for Management Reporter
Select Chart of Accounts
Activate Horizontal Scroll Bars for All Existing Users
Workflow Assignment Review
Update Item Replenishment Method for Manufacturing
Get Alpha Characters from an Alphanumeric String
Set Vendor On Hold If EFT Details Changed
List Open Purchase Order Lines
SQL View to Create Division, including UDF 3 and 4, Tree for Management Reporter
Delete Orphaned Vendor EFT Details
Sales Invoice Query
Round Extended Pricing Price Sheet Item Value
Get Numeric Characters from an Alphanumeric String
Trigger to Activate Horizontal Scroll Bars for New Users
View to Return List of Payments and Linked Invoices
Select Duplicate Extended Pricing Price Sheet Work Records
RM Aged Debt Report
Select Next Temporary Creditor ID
Select a List of Vendor Addresses
Set Vendor On Hold When Created
Assembly Transaction Quantities Required
Generate Standard Cost Update Macro from Text File Import
Check for Corrupt Extended Pricing Records
Sales Line Items
Compare Ship To Address on Work Sales Trx Against Customer
SQL View to Return PO Commitment Detail
List Bank Accounts with Linked GL Accounts
Validate and Insert/Update Vendor Emails from a Text File
Return Items with Incorrect Quantities
Set Account Categories To User-Defined Field 2
Check Posting Type for Account (Segment 2)/Account Category Combinations
Update Ship To Name on Work Sales Transactions to Match the Customer Name
List Tax Detail Transactions
Select Tax Details and Related G/L Accounts
Update Account Description by Adding 3rd Segment Description
Update Segment Descriptions from Other Database
Return Opening Balance for Period of Supplied Date
Update Min Order Qty and Average Lead Time on Vendor Item From Text File
List of PM Invoices for Vendors with POs
Select Debit, Credit and Net Change for All Accounts in Date Range
Select All Pending Prepayments
Available Stock for All Items
Item Report
Migrate Vendor Emails from Active Docs to Standard Email Fields
Update Mfg Cost Accounts from Mfg Item Class Setup
PO Commitment Detail
Update Inventory Accounts from Item Class
Create Macro to Delete Items
Update Accounts Payable Distribution on Work Status PM Transactions from Posting Account Setup
Update Item Resource Planning on Item Quantity Master from Text File
SQL View to Return List of Posted Vendor Document Numbers
Update Inventory Distribution on Work Status Purchase Orders from the Item Card
Update Item Engineering File from a Text File
List of Exchange Rates

SQL View to Return the Accounting Period Starting and Ending Dates in Microsoft Dynamics 365 Business Central

Microsoft Dynamics 365 Business CentralWhile Microsoft Dynamics 365 Business Central is mainly used by clients in the cloud rather than on-premise, there are still some clients using the on-premise version. I was talking to one recently who was looking to create some transactional reports and needed to get the start and end dates for the accounting periods. For some clients, who use calendar months, this would be easy, but in the UK many companies use a 5-5-4 cycle of months starting from the first Monday of April.

When I did some exploring of the database, I found that the Accounting Period table holds the start date but not the end date of periods. SO what I needed to do was to calculate the end date based on the start date if the next period.

The below SQL view returns the start and end dates of each period:

-- drop view if it exists
IF OBJECT_ID(N'uv_AZRCRV_GetAccountingPeriodDates', N'V') IS NOT NULL
	DROP VIEW uv_AZRCRV_GetAccountingPeriodDates
GO
-- create view
CREATE VIEW uv_AZRCRV_GetAccountingPeriodDates 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). */
WITH AccountingPeriods AS ( SELECT [Starting Date] ,[Name] ,ROW_NUMBER() OVER (ORDER BY [Starting Date] ASC) AS [Line Number] FROM [CRONUS UK Ltd_$Accounting Period$437dbf0e-84ff-417a-965d-ed2bb9650972] ) SELECT [Starting Date].[Starting Date] ,DATEADD( DAY, -1, [Ending Date].[Starting Date] ) AS [Ending Date] ,[Starting Date].[Name] ,[Starting Date].[Line Number] FROM AccountingPeriods AS [Starting Date] LEFT JOIN AccountingPeriods AS [Ending Date] ON [Ending Date].[Line Number] = [Starting Date].[Line Number] + 1 GO GRANT SELECT ON uv_AZRCRV_GetAccountingPeriodDates TO [Reporting Users] GO