SQL Scripts for Microsoft Dynamics GP: Remove Multicurrency from Sales Transactions

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 was created for a client who imported a batch of transactions with the incorrect multicurrency information; this was only found when they came to post the transactions and found that they would not post. The transactions were in the functional currency of EURO, but had a US Dollar exchange rate applied to them.

The script was set up to allow the Currency ID and Exchange Table ID to be specified and the Sales Taxes Work and History (SOP10105) and Sales Transaction Work (SOP10100) tables updated to remove the incorrect multicurrency information.

/*
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). */
DECLARE @CURNCYID VARCHAR(15) = 'EURO' DECLARE @EXGTBLID VARCHAR(15) = 'EUR-USD' UPDATE SOP10105 --Sales Taxes Work and History (SOP10105) SET ORSLSTAX = STAXAMNT ,ORTOTSLS = TAXDTSLS ,ORTXSLS = TDTTXSLS ,OTTAXPON = TXDTOTTX WHERE SOPNUMBE IN ( SELECT SOPNUMBE FROM SOP10100 AS SOPH --Sales Transaction Work (SOP10100) WHERE CURNCYID = @CURNCYID AND RATETPID <> '' AND EXGTBLID = @EXGTBLID ) AND STAXAMNT <> ORSLSTAX UPDATE SOP10100 --Sales Transaction Work (SOP10100) SET ORDOCAMT = DOCAMNT ,ORSUBTOT = SUBTOTAL ,ORTAXAMT = TAXAMNT ,RATETPID = '' ,EXGTBLID = '' ,XCHGRATE = 0 WHERE SOPNUMBE IN ( SELECT SOPNUMBE FROM SOP10100 AS SOPH --Sales Transaction Work (SOP10100) WHERE CURNCYID = @CURNCYID AND RATETPID <> '' AND EXGTBLID = @EXGTBLID ) AND DOCAMNT <> ORDOCAMT

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

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

Excel Snippets: Offset Formula to Calculate Range on Number

MicrosoftI might not post many Excel snippets, but I’m collecting them into a small Excel Snippets series to make them easy to find.

This is based on an example a colleague discussed with me for dynamically calculating the sum of a range of columns based on the user specificed number of months.

The data for the months of the year was going across the worksheet with a total at the end, but he only wanted to total up the rows up to the required month. The example below shows the required output, with the user specifying month 7 (July) in cell B1 and the required total value in cell O3 which is the sum of C3:N3:

Example data in Excel

If we’d wanted the whole row, this would have been quite easy to do using the SUM formula:

=SUM(C3:N3)

The problem is though, that the second cell in the range needed to be variable. Fortunately, Excel has another function which we can use; that function is OFFSET:

=OFFSET(cell reference, rows, columns))

In our example, we needed to set the cell reference parameter to B3, the rows to 0 and the columns to B1:

=OFFSET(B3,0,B1))

This OFFSET will, when combined with the SUM formula, give us the result we need of summing from B3 through the columns to I3 when month 7 (July) is speficied by the user in cell B1:

=SUM(C3:OFFSET(B3,0,B1))