SQL Scripts for Microsoft Dynamics GP: Select All Pending Prepayments

Microsoft Dynamics GPThis script is part of the SQL Scripts for Microsoft Dynamics GP where I will be posting the scripts I wrote against Microsoft Dynamics GP over the 19 years before I stopped working with Dynamics GP.

This script will return a list of all pending prepayments in Dynamics GP; the highlighted account at the can be changed or removed as required.

CREATE VIEW [dbo].[uv_AZRCRV_PendingPrepayments] 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 ['PM Transaction WORK File'].VCHRNMBR AS 'Voucher Number' ,CASE ['PM Transaction WORK File'].DOCTYPE WHEN 1 THEN 'Invoice' WHEN 5 THEN 'Credit Memo' ELSE '' END AS 'Document Type' ,['PM Creditor Master'].VENDORID AS 'Creditor ID' ,['PM Creditor Master'].VENDNAME AS 'Creditor Name' ,FORMAT(EOMONTH(DATEADD(month,-1,GETDATE())), 'dd/MM/yyyy') AS 'Transaction Date' ,['PM Transaction WORK File'].BACHNUMB AS 'Batch Number' ,['PM Transaction WORK File'].TRXDSCRN AS 'Document Description' ,['PM Transaction WORK File'].DOCNUMBR AS 'Document Number' ,['PM Transaction WORK File'].PORDNMBR AS 'PO Number' ,ISNULL(['Deferral Account Index Master'].ACTNUMST,['GL Account Index Master'].ACTNUMST) AS 'Account' ,['PM Distribution WORK OPEN'].DEBITAMT AS 'Debit' ,['PM Distribution WORK OPEN'].CRDTAMNT AS 'Credit' ,CASE WHEN DOCTYPE = 1 THEN CASE WHEN ['Deferral Header Work'].PP_Module IS NOT NULL THEN SUM(['Deferral Line Work'].TRXAMNT) ELSE 0 --SUM(['PM Distribution WORK OPEN'].DEBITAMT) END ELSE 0 END AS 'Deferred Debit' ,CASE WHEN DOCTYPE = 1 THEN 0 ELSE CASE WHEN ['Deferral Header Work'].PP_Module IS NOT NULL THEN SUM(['Deferral Line Work'].TRXAMNT) ELSE 0 --SUM(['PM Distribution WORK OPEN'].CRDTAMNT) END END AS 'Deferred Credit' ,['PM Distribution WORK OPEN'].DistRef AS 'Distribution Reference' ,CASE WHEN ['Deferral Header Work'].PP_Module IS NULL THEN 'Not Deferred' ELSE 'Deferred' END AS 'Deferred' FROM PM10000 AS ['PM Transaction WORK File'] -- FOR OPEN CHANGE TO PM20000 INNER JOIN PM00200 AS ['PM Creditor Master'] ON ['PM Creditor Master'].VENDORID = ['PM Transaction WORK File'].VENDORID INNER JOIN PM10100 AS ['PM Distribution WORK OPEN'] ON ['PM Distribution WORK OPEN'].CNTRLTYP = ['PM Transaction WORK File'].CNTRLTYP AND ['PM Distribution WORK OPEN'].VCHRNMBR = ['PM Transaction WORK File'].VCHRNMBR INNER JOIN GL00105 AS ['GL Account Index Master'] ON ['GL Account Index Master'].ACTINDX = ['PM Distribution WORK OPEN'].DSTINDX LEFT JOIN -- Join to RED PP000100 AS ['Deferral Header Work'] -- FOR OPEN CHANGE TO PP100100 ON ['Deferral Header Work'].CNTRLTYP = ['PM Distribution WORK OPEN'].CNTRLTYP AND ['Deferral Header Work'].PP_Document_Number = ['PM Distribution WORK OPEN'].VCHRNMBR AND ['Deferral Header Work'].PP_Sequencer = ['PM Distribution WORK OPEN'].DSTSQNUM LEFT JOIN GL00105 AS ['Deferral Account Index Master'] ON ['Deferral Account Index Master'].ACTINDX = ['Deferral Header Work'].ACTINDX LEFT JOIN PP000101 AS ['Deferral Line Work'] ON ['Deferral Line Work'].PP_Module = ['Deferral Header Work'].PP_Module AND ['Deferral Line Work'].PP_Record_Type = ['Deferral Header Work'].PP_Record_Type AND ['Deferral Line Work'].PP_Document_Number = ['Deferral Header Work'].PP_Document_Number AND ['Deferral Line Work'].PP_Sequencer = ['Deferral Header Work'].PP_Sequencer AND ['Deferral Line Work'].PPOFFSEQ = ['Deferral Header Work'].PPOFFSEQ AND ['Deferral Line Work'].CNTRLTYP = ['Deferral Header Work'].CNTRLTYP AND ['Deferral Line Work'].VCHRNMBR = ['Deferral Header Work'].VCHRNMBR AND ['Deferral Line Work'].DSTSQNUM = ['Deferral Header Work'].DSTSQNUM WHERE ['PM Transaction WORK File'].BCHSOURC = 'PM_Trxent' AND ['PM Distribution WORK OPEN'].DISTTYPE = 6 --Include only Purchases Distribution GROUP BY ['GL Account Index Master'].ACTNUMST ,['Deferral Account Index Master'].ACTNUMST ,['PM Transaction WORK File'].DOCTYPE ,['Deferral Header Work'].PP_Module ,['PM Distribution WORK OPEN'].DistRef ,['PM Transaction WORK File'].VCHRNMBR ,['PM Creditor Master'].VENDORID ,['PM Creditor Master'].VENDNAME ,['PM Transaction WORK File'].DOCTYPE ,['PM Transaction WORK File'].BACHNUMB ,['PM Transaction WORK File'].TRXDSCRN ,['PM Transaction WORK File'].DOCNUMBR ,['PM Transaction WORK File'].PORDNMBR ,['PM Distribution WORK OPEN'].DEBITAMT ,['PM Distribution WORK OPEN'].CRDTAMNT HAVING ['GL Account Index Master'].ACTNUMST = '000-8888-00' 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

Set Recurring Frequency on a Recurring Journal in Microsoft Dynamics 365 Business Central

Microsoft Dynamics 365 Business CentralFor a recent training session on the general ledger in Microsoft Dynamics 365 Business Central, I covered recurring journals with the client. One of the requirements, for accruals, is that the journal be posted on the last day of the month.

If every month was of an equal length this would be quite easy to do using a date formula of 1M, but they aren;t so a more complex date formula is required.

To post the journal on the last day of a month, every month, the date formula required is 1D+1M-1D, which means add 1 day, add 1 month and subtract 1 day from the posting date. With this formula Business Central calculates the date correctly regardless of how many days are in the month.