SQL Scripts for Microsoft Dynamics GP: GL Account Transactions With Amount in One Column

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 a while ago for a client who wanted a SQL query to use in SSRS; it was put together in conjunction with the finance team to return the data exactly as they wanted (including one column with the amount shown as a positive or negative) it and then passed across to someone in IT to wrap the SSRS report around it.

/*
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 GLT.SOURCDOC AS 'Source Document' ,GLT.JRNENTRY AS 'Journal Entry' ,GLT.SERIES AS 'Series' ,GLT.TRXDATE AS 'TRX Date' ,GL105.ACTNUMST AS 'Account Number' ,GL100.ACTDESCR AS 'Account Description' ,GLT.Amount AS 'Amount' ,GLT.PERIODID AS 'Period ID' ,GLT.USWHPSTD AS 'User Who Posted' ,GLT.REFRENCE AS 'Reference' ,GLT.DSCRIPTN AS 'Description' ,GL105.ACTNUMBR_3 AS 'Segment 3' ,GLT.ORMSTRNM AS 'Original Master Name' ,GL100.USERDEF2 AS 'User Defined 2' ,GL100.USRDEFS1 AS 'User Defined 3' ,GL100.USRDEFS2 AS 'User Defined 4' ,GL100.ACTNUMBR_1 AS 'Segment 1' ,GLT.ORCTRNUM AS 'Originating Control Number' FROM (SELECT ACTINDX,OPENYEAR AS 'Year',GLH.JRNENTRY,TRXDATE,SOURCDOC,SERIES,CASE WHEN DEBITAMT > 0 THEN DEBITAMT ELSE CRDTAMNT *-1 END AS 'Amount' ,PERIODID,USWHPSTD,REFRENCE,DSCRIPTN,ORMSTRNM,ORCTRNUM FROM GL10001 AS GLL WITH (NOLOCK) INNER JOIN GL10000 AS GLH WITH (NOLOCK) ON GLH.JRNENTRY = GLL.JRNENTRY UNION ALL SELECT ACTINDX,OPENYEAR AS 'Year', JRNENTRY,TRXDATE,SOURCDOC,SERIES,CASE WHEN DEBITAMT > 0 THEN DEBITAMT ELSE CRDTAMNT *-1 END AS 'Amount' ,PERIODID,USWHPSTD,REFRENCE,DSCRIPTN,ORMSTRNM,ORCTRNUM FROM GL20000 WITH (NOLOCK) UNION ALL SELECT ACTINDX,HSTYEAR AS 'Year',JRNENTRY,TRXDATE,SOURCDOC,SERIES,CASE WHEN DEBITAMT > 0 THEN DEBITAMT ELSE CRDTAMNT *-1 END AS 'Amount' ,PERIODID,USWHPSTD,REFRENCE,DSCRIPTN,ORMSTRNM,ORCTRNUM FROM GL30000 WITH (NOLOCK) ) AS GLT INNER JOIN GL00105 AS GL105 WITH (NOLOCK) ON GL105.ACTINDX = GLT.ACTINDX INNER JOIN GL00100 AS GL100 WITH (NOLOCK) ON GL100.ACTINDX = GL105.ACTINDX

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.

Your Name

Your Email

Suggested Topic

Suggestion Details

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.

Leave a Reply

Your email address will not be published. Required fields are marked *