SQL Script for AP-GL Reconciliation

| 01/17/2012 | 7 Comments

Hi all

It has been some time since I have posted something useful on my blog. This was because I was busy writing up and testing the reconciliation script that I had developed to reconcile payables and receivables with the general ledger.

In this article, I have posted a script to reconcile payables with general ledger. I have tested it with a couple of live environments and it looks to be working fine. However, there might still be an unseen scenario which I might not have uncovered. Please let me know if there are any such scenarios which I might have missed out, so that I can incorporate the same in this.

/******************************************************************
Created Jan 17, 2012 by Sivakumar Venkataraman - Interdyn AKA
This view is for the reconcile the payables amounts with 
the corresponding amounts in the general ledger. 
 
Revision History
No.		Date			Description
1		01/17/2012		Original Version
2		03/07/2012		Updated the script to support multiple
						AP Account Indexes
*******************************************************************/
 
DECLARE @DELIMITER CHAR(1)
DECLARE @EMPTYDATE AS DATETIME
DECLARE @ASOFDATE AS DATETIME
DECLARE @APACCOUNTS AS VARCHAR(50)
 
--Define the delimiter
SET @DELIMITER = '|'
--Leave this always as 1900-01-01. Do not change this. 
SET @EMPTYDATE = '1900-01-01' 
--This is the as of date to which we need to reconcile.
SET @ASOFDATE = '2017-04-12'
--Separate multiple account indexes by a comma
SET @APACCOUNTS = '35|36|37'
 
SELECT  APGL.*
FROM    ( SELECT  AP.*
          FROM    ( SELECT  APRECON.VENDORID ,
                            APRECON.DOCNUMBR ,
                            ISNULL(CONVERT(VARCHAR(20), APRECON.JRNENTRY), '') AS JRNENTRY ,
                            DT.DOCTYNAM AS DOCTYPE ,
                            APRECON.TRXSORCE AS AUDITTRAIL ,
                            APRECON.SLAMOUNT ,
                            APRECON.GLAMOUNT ,
                            CASE WHEN APRECON.GLAMOUNT = APRECON.SLAMOUNT
                                      AND APRECON.DOCSTATUS <> 'Work' THEN 'Matched'
                                 WHEN APRECON.DOCSTATUS = 'Work' THEN 'Unposted in GL, Posted in SL'
                                 WHEN APRECON.GLAMOUNT = 0 THEN 'Not in GL, Posted in SL'
                                 WHEN APRECON.GLAMOUNT <> APRECON.SLAMOUNT THEN 'Mismatched'
                            END AS RECONSTATUS
                    FROM    ( SELECT  AP.VENDORID ,
                                      AP.DOCNUMBR ,
                                      AP.DOCTYPE ,
                                      AP.TRXSORCE ,
                                      AP.MATCHKEY ,
                                      AP.APAMOUNT AS SLAMOUNT ,
                                      GL.JRNENTRY ,
                                      GL.DOCSTATUS ,
                                      ISNULL(GL.APAMOUNT, 0) AS GLAMOUNT
                              FROM    ( SELECT  W.VENDORID ,
                                                W.DOCNUMBR ,
                                                W.DOCTYPE ,
                                                W.TRXSORCE ,
                                                LTRIM(RTRIM(W.VENDORID)) + '-' + LTRIM(RTRIM(W.DOCTYPE)) + '-'
                                                + LTRIM(RTRIM(W.DOCNUMBR)) + LTRIM(RTRIM(W.TRXSORCE)) AS MATCHKEY ,
                                                SUM(W.DOCUMENTAMT) AS APAMOUNT
                                        FROM    ( SELECT  X.VENDORID ,
                                                          X.VCHRNMBR ,
                                                          X.DOCTYPE ,
                                                          X.DOCNUMBR ,
                                                          X.DOCDATE ,
                                                          X.TRXSORCE ,
                                                          X.VOIDED ,
                                                          X.PSTGDATE ,
                                                          X.VOIDPDATE ,
                                                          CASE WHEN X.DOCTYPE <= 3 THEN X.DOCUMENTAMT * -1
                                                               ELSE X.DOCUMENTAMT
                                                          END AS DOCUMENTAMT ,
                                                          X.APPLIEDAMT ,
                                                          X.WRITEOFFAMT ,
                                                          X.DISCTAKENAMT ,
                                                          X.REALGAINLOSSAMT ,
                                                          CASE WHEN X.DOCTYPE <= 3
                                                               THEN ( X.DOCUMENTAMT - X.APPLIEDAMT - X.WRITEOFFAMT
                                                                      - X.DISCTAKENAMT + X.REALGAINLOSSAMT )
                                                               ELSE ( X.DOCUMENTAMT - X.APPLIEDAMT - X.WRITEOFFAMT
                                                                      - X.DISCTAKENAMT + X.REALGAINLOSSAMT ) * -1
                                                          END AS CURTRXAMT
                                                  FROM    ( SELECT  Z.VCHRNMBR ,
                                                                    Z.VENDORID ,
                                                                    Z.DOCTYPE ,
                                                                    Z.DOCDATE ,
                                                                    Z.DOCNUMBR ,
                                                                    Z.DOCAMNT AS DOCUMENTAMT ,
                                                                    CASE WHEN DOCTYPE <= 3
                                                                         THEN ISNULL(( SELECT SUM(Y.APPLDAMT)
                                                                                       FROM   ( SELECT  VENDORID ,
                                                                                                        ApplyFromGLPostDate ,
                                                                                                        GLPOSTDT ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        APPLDAMT
                                                                                                FROM    dbo.PM10200
                                                                                                UNION
                                                                                                SELECT  VENDORID ,
                                                                                                        ApplyFromGLPostDate ,
                                                                                                        GLPOSTDT ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        APPLDAMT
                                                                                                FROM    dbo.PM30300
                                                                                              ) Y
                                                                                       WHERE  Y.GLPOSTDT <= @ASOFDATE
                                                                                              AND Y.ApplyFromGLPostDate <= @ASOFDATE
                                                                                              AND Y.ApplyFromGLPostDate <> @EMPTYDATE
                                                                                              AND Y.VENDORID = Z.VENDORID
                                                                                              AND Y.APTVCHNM = Z.VCHRNMBR
                                                                                              AND Y.APTODCTY = Z.DOCTYPE
                                                                                     ), 0)
                                                                         WHEN DOCTYPE > 3
                                                                              AND DOCTYPE <= 6
                                                                         THEN ISNULL(( SELECT SUM(Y.APPLDAMT)
                                                                                       FROM   ( SELECT  VENDORID ,
                                                                                                        GLPOSTDT ,
                                                                                                        APPLDAMT ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        ApplyToGLPostDate
                                                                                                FROM    dbo.PM10200
                                                                                                UNION
                                                                                                SELECT  VENDORID ,
                                                                                                        GLPOSTDT ,
                                                                                                        APPLDAMT ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        ApplyToGLPostDate
                                                                                                FROM    dbo.PM30300
                                                                                              ) Y
                                                                                       WHERE  Y.GLPOSTDT <= @ASOFDATE
                                                                                              AND Y.ApplyToGLPostDate <= @ASOFDATE
                                                                                              AND Y.ApplyToGLPostDate <> @EMPTYDATE
                                                                                              AND Y.VENDORID = Z.VENDORID
                                                                                              AND Y.VCHRNMBR = Z.VCHRNMBR
                                                                                              AND Y.DOCTYPE = Z.DOCTYPE
                                                                                     ), 0)
                                                                         ELSE 0
                                                                    END AS APPLIEDAMT ,
                                                                    CASE WHEN DOCTYPE <= 3
                                                                         THEN ISNULL(( SELECT SUM(Y.WROFAMNT)
                                                                                       FROM   ( SELECT  VENDORID ,
                                                                                                        ApplyFromGLPostDate ,
                                                                                                        GLPOSTDT ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        WROFAMNT
                                                                                                FROM    dbo.PM10200
                                                                                                UNION
                                                                                                SELECT  VENDORID ,
                                                                                                        ApplyFromGLPostDate ,
                                                                                                        GLPOSTDT ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        WROFAMNT
                                                                                                FROM    dbo.PM30300
                                                                                              ) Y
                                                                                       WHERE  Y.GLPOSTDT <= @ASOFDATE
                                                                                              AND Y.ApplyFromGLPostDate <= @ASOFDATE
                                                                                              AND Y.ApplyFromGLPostDate <> @EMPTYDATE
                                                                                              AND Y.VENDORID = Z.VENDORID
                                                                                              AND Y.APTVCHNM = Z.VCHRNMBR
                                                                                              AND Y.APTODCTY = Z.DOCTYPE
                                                                                     ), 0)
                                                                         ELSE 0
                                                                    END AS WRITEOFFAMT ,
                                                                    CASE WHEN DOCTYPE <= 3
                                                                         THEN ISNULL(( SELECT SUM(Y.DISTKNAM)
                                                                                       FROM   ( SELECT  VENDORID ,
                                                                                                        ApplyFromGLPostDate ,
                                                                                                        GLPOSTDT ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        DISTKNAM
                                                                                                FROM    dbo.PM10200
                                                                                                UNION
                                                                                                SELECT  VENDORID ,
                                                                                                        ApplyFromGLPostDate ,
                                                                                                        GLPOSTDT ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        DISTKNAM
                                                                                                FROM    dbo.PM30300
                                                                                              ) Y
                                                                                       WHERE  Y.GLPOSTDT <= @ASOFDATE
                                                                                              AND Y.ApplyFromGLPostDate <= @ASOFDATE
                                                                                              AND Y.ApplyFromGLPostDate <> @EMPTYDATE
                                                                                              AND Y.VENDORID = Z.VENDORID
                                                                                              AND Y.APTVCHNM = Z.VCHRNMBR
                                                                                              AND Y.APTODCTY = Z.DOCTYPE
                                                                                     ), 0)
                                                                         ELSE 0
                                                                    END AS DISCTAKENAMT ,
                                                                    CASE WHEN DOCTYPE > 3
                                                                         THEN ISNULL(( SELECT SUM(Y.RLGANLOS)
                                                                                       FROM   ( SELECT  VENDORID ,
                                                                                                        GLPOSTDT ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        ApplyToGLPostDate ,
                                                                                                        RLGANLOS
                                                                                                FROM    dbo.PM10200
                                                                                                UNION
                                                                                                SELECT  VENDORID ,
                                                                                                        GLPOSTDT ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        ApplyToGLPostDate ,
                                                                                                        RLGANLOS
                                                                                                FROM    dbo.PM30300
                                                                                              ) Y
                                                                                       WHERE  Y.GLPOSTDT <= @ASOFDATE
                                                                                              AND Y.ApplyToGLPostDate <= @ASOFDATE
                                                                                              AND Y.ApplyToGLPostDate <> @EMPTYDATE
                                                                                              AND Y.VENDORID = Z.VENDORID
                                                                                              AND Y.VCHRNMBR = Z.VCHRNMBR
                                                                                              AND Y.DOCTYPE = Z.DOCTYPE
                                                                                     ), 0)
                                                                         ELSE 0
                                                                    END AS REALGAINLOSSAMT ,
                                                                    Z.TRXSORCE ,
                                                                    Z.VOIDED ,
                                                                    Z.PSTGDATE ,
                                                                    Z.VOIDPDATE
                                                            FROM    ( SELECT  VCHRNMBR ,
                                                                              VENDORID ,
                                                                              DOCTYPE ,
                                                                              DOCDATE ,
                                                                              DOCNUMBR ,
                                                                              DOCAMNT ,
                                                                              BACHNUMB ,
                                                                              TRXSORCE ,
                                                                              BCHSOURC ,
                                                                              DISCDATE ,
                                                                              VOIDED ,
                                                                              PSTGDATE ,
                                                                              @EMPTYDATE AS VOIDPDATE
                                                                      FROM    dbo.PM20000
                                                                      UNION ALL
                                                                      SELECT  VCHRNMBR ,
                                                                              VENDORID ,
                                                                              DOCTYPE ,
                                                                              DOCDATE ,
                                                                              DOCNUMBR ,
                                                                              DOCAMNT ,
                                                                              BACHNUMB ,
                                                                              TRXSORCE ,
                                                                              BCHSOURC ,
                                                                              DISCDATE ,
                                                                              VOIDED ,
                                                                              PSTGDATE ,
                                                                              VOIDPDATE
                                                                      FROM    dbo.PM30200
                                                                    ) Z
                                                            WHERE   Z.PSTGDATE <= @ASOFDATE
                                                                    AND Z.VOIDED = 0
                                                          ) X
                                                  UNION ALL
                                                  SELECT  X.VENDORID ,
                                                          X.VCHRNMBR ,
                                                          X.DOCTYPE ,
                                                          X.DOCNUMBR ,
                                                          X.DOCDATE ,
                                                          X.TRXSORCE ,
                                                          X.VOIDED ,
                                                          X.PSTGDATE ,
                                                          X.VOIDPDATE ,
                                                          X.DOCUMENTAMT ,
                                                          X.APPLIEDAMT ,
                                                          X.WRITEOFFAMT ,
                                                          X.DISCTAKENAMT ,
                                                          X.REALGAINLOSSAMT ,
                                                          ( X.DOCUMENTAMT - X.APPLIEDAMT - X.WRITEOFFAMT
                                                            - X.DISCTAKENAMT + X.REALGAINLOSSAMT ) * -1 AS CURTRXAMT
                                                  FROM    ( SELECT  Z.VCHRNMBR ,
                                                                    Z.VENDORID ,
                                                                    Z.DOCTYPE ,
                                                                    Z.DOCDATE ,
                                                                    Z.DOCNUMBR ,
                                                                    Z.DOCAMNT AS DOCUMENTAMT ,
                                                                    CASE WHEN DOCTYPE <= 3
                                                                         THEN ISNULL(( SELECT SUM(Y.APPLDAMT)
                                                                                       FROM   ( SELECT  VENDORID ,
                                                                                                        ApplyFromGLPostDate ,
                                                                                                        GLPOSTDT ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        APPLDAMT
                                                                                                FROM    dbo.PM10200
                                                                                                UNION
                                                                                                SELECT  VENDORID ,
                                                                                                        ApplyFromGLPostDate ,
                                                                                                        GLPOSTDT ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        APPLDAMT
                                                                                                FROM    dbo.PM30300
                                                                                              ) Y
                                                                                       WHERE  Y.GLPOSTDT <= @ASOFDATE
                                                                                              AND Y.ApplyFromGLPostDate <= @ASOFDATE
                                                                                              AND Y.ApplyFromGLPostDate <> @EMPTYDATE
                                                                                              AND Y.VENDORID = Z.VENDORID
                                                                                              AND Y.APTVCHNM = Z.VCHRNMBR
                                                                                              AND Y.APTODCTY = Z.DOCTYPE
                                                                                     ), 0)
                                                                         WHEN DOCTYPE > 3
                                                                              AND DOCTYPE <= 6
                                                                         THEN ISNULL(( SELECT SUM(Y.APPLDAMT)
                                                                                       FROM   ( SELECT  VENDORID ,
                                                                                                        GLPOSTDT ,
                                                                                                        APPLDAMT ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        ApplyToGLPostDate
                                                                                                FROM    dbo.PM10200
                                                                                                UNION
                                                                                                SELECT  VENDORID ,
                                                                                                        GLPOSTDT ,
                                                                                                        APPLDAMT ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        ApplyToGLPostDate
                                                                                                FROM    dbo.PM30300
                                                                                              ) Y
                                                                                       WHERE  Y.GLPOSTDT <= @ASOFDATE
                                                                                              AND Y.ApplyToGLPostDate <= @ASOFDATE
                                                                                              AND Y.ApplyToGLPostDate <> @EMPTYDATE
                                                                                              AND Y.VENDORID = Z.VENDORID
                                                                                              AND Y.VCHRNMBR = Z.VCHRNMBR
                                                                                              AND Y.DOCTYPE = Z.DOCTYPE
                                                                                     ), 0)
                                                                         ELSE 0
                                                                    END AS APPLIEDAMT ,
                                                                    CASE WHEN DOCTYPE <= 3
                                                                         THEN ISNULL(( SELECT SUM(Y.WROFAMNT)
                                                                                       FROM   ( SELECT  VENDORID ,
                                                                                                        ApplyFromGLPostDate ,
                                                                                                        GLPOSTDT ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        WROFAMNT
                                                                                                FROM    dbo.PM10200
                                                                                                UNION
                                                                                                SELECT  VENDORID ,
                                                                                                        ApplyFromGLPostDate ,
                                                                                                        GLPOSTDT ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        WROFAMNT
                                                                                                FROM    dbo.PM30300
                                                                                              ) Y
                                                                                       WHERE  Y.GLPOSTDT <= @ASOFDATE
                                                                                              AND Y.ApplyFromGLPostDate <= @ASOFDATE
                                                                                              AND Y.ApplyFromGLPostDate <> @EMPTYDATE
                                                                                              AND Y.VENDORID = Z.VENDORID
                                                                                              AND Y.APTVCHNM = Z.VCHRNMBR
                                                                                              AND Y.APTODCTY = Z.DOCTYPE
                                                                                     ), 0)
                                                                         ELSE 0
                                                                    END AS WRITEOFFAMT ,
                                                                    CASE WHEN DOCTYPE <= 3
                                                                         THEN ISNULL(( SELECT SUM(Y.DISTKNAM)
                                                                                       FROM   ( SELECT  VENDORID ,
                                                                                                        ApplyFromGLPostDate ,
                                                                                                        GLPOSTDT ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        DISTKNAM
                                                                                                FROM    dbo.PM10200
                                                                                                UNION
                                                                                                SELECT  VENDORID ,
                                                                                                        ApplyFromGLPostDate ,
                                                                                                        GLPOSTDT ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        DISTKNAM
                                                                                                FROM    dbo.PM30300
                                                                                              ) Y
                                                                                       WHERE  Y.GLPOSTDT <= @ASOFDATE
                                                                                              AND Y.ApplyFromGLPostDate <= @ASOFDATE
                                                                                              AND Y.ApplyFromGLPostDate <> @EMPTYDATE
                                                                                              AND Y.VENDORID = Z.VENDORID
                                                                                              AND Y.APTVCHNM = Z.VCHRNMBR
                                                                                              AND Y.APTODCTY = Z.DOCTYPE
                                                                                     ), 0)
                                                                         ELSE 0
                                                                    END AS DISCTAKENAMT ,
                                                                    CASE WHEN DOCTYPE > 3
                                                                         THEN ISNULL(( SELECT SUM(Y.RLGANLOS)
                                                                                       FROM   ( SELECT  VENDORID ,
                                                                                                        GLPOSTDT ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        ApplyToGLPostDate ,
                                                                                                        RLGANLOS
                                                                                                FROM    dbo.PM10200
                                                                                                UNION
                                                                                                SELECT  VENDORID ,
                                                                                                        GLPOSTDT ,
                                                                                                        VCHRNMBR ,
                                                                                                        DOCTYPE ,
                                                                                                        APTVCHNM ,
                                                                                                        APTODCTY ,
                                                                                                        ApplyToGLPostDate ,
                                                                                                        RLGANLOS
                                                                                                FROM    dbo.PM30300
                                                                                              ) Y
                                                                                       WHERE  Y.GLPOSTDT <= @ASOFDATE
                                                                                              AND Y.ApplyToGLPostDate <= @ASOFDATE
                                                                                              AND Y.ApplyToGLPostDate <> @EMPTYDATE
                                                                                              AND Y.VENDORID = Z.VENDORID
                                                                                              AND Y.VCHRNMBR = Z.VCHRNMBR
                                                                                              AND Y.DOCTYPE = Z.DOCTYPE
                                                                                     ), 0)
                                                                         ELSE 0
                                                                    END AS REALGAINLOSSAMT ,
                                                                    Z.TRXSORCE ,
                                                                    Z.VOIDED ,
                                                                    Z.PSTGDATE ,
                                                                    Z.VOIDPDATE
                                                            FROM    ( SELECT  VCHRNMBR ,
                                                                              VENDORID ,
                                                                              DOCTYPE ,
                                                                              DOCDATE ,
                                                                              DOCNUMBR ,
                                                                              DOCAMNT ,
                                                                              BACHNUMB ,
                                                                              TRXSORCE ,
                                                                              BCHSOURC ,
                                                                              DISCDATE ,
                                                                              VOIDED ,
                                                                              PSTGDATE ,
                                                                              @EMPTYDATE AS VOIDPDATE
                                                                      FROM    dbo.PM20000
                                                                      UNION
                                                                      SELECT  VCHRNMBR ,
                                                                              VENDORID ,
                                                                              DOCTYPE ,
                                                                              DOCDATE ,
                                                                              DOCNUMBR ,
                                                                              DOCAMNT ,
                                                                              BACHNUMB ,
                                                                              TRXSORCE ,
                                                                              BCHSOURC ,
                                                                              DISCDATE ,
                                                                              VOIDED ,
                                                                              PSTGDATE ,
                                                                              VOIDPDATE
                                                                      FROM    dbo.PM30200
                                                                    ) Z
                                                            WHERE   Z.PSTGDATE <= @ASOFDATE
                                                                    AND Z.VOIDED = 1
                                                                    AND Z.VOIDPDATE > @ASOFDATE
                                                          ) X
                                                ) W
                                        GROUP BY W.VENDORID ,
                                                W.DOCTYPE ,
                                                W.DOCNUMBR ,
                                                W.TRXSORCE
                                      ) AP
                                      LEFT OUTER JOIN ( SELECT  LTRIM(RTRIM(W.VENDORID)) + '-'
                                                                + LTRIM(RTRIM(W.DOCUMENTTYPE)) + '-'
                                                                + LTRIM(RTRIM(W.DOCUMENTNUMBER))
                                                                + LTRIM(RTRIM(W.ORIGSOURCE)) AS MATCHKEY ,
                                                                W.DOCSTATUS ,
                                                                W.JRNENTRY ,
                                                                W.APAMOUNT AS APAMOUNT
                                                        FROM    ( SELECT  'Open' AS DOCSTATUS ,
                                                                          ORMSTRID AS VENDORID ,
                                                                          CASE WHEN ORTRXTYP IN ( 2, 3 ) THEN 1
                                                                               ELSE ORTRXTYP
                                                                          END AS DOCUMENTTYPE ,
                                                                          CASE WHEN ORTRXTYP IN ( 2, 3 )
                                                                               THEN ( SELECT  VNDDOCNM
                                                                                      FROM    dbo.POP30300 A1
                                                                                      WHERE   A1.POPRCTNM = ORDOCNUM
                                                                                    )
                                                                               ELSE ORDOCNUM
                                                                          END AS DOCUMENTNUMBER ,
                                                                          JRNENTRY ,
                                                                          ORTRXSRC AS ORIGSOURCE ,
                                                                          SUM(DEBITAMT - CRDTAMNT) AS APAMOUNT
                                                                  FROM    dbo.GL20000
                                                                  WHERE   ACTINDX IN (
                                                                          SELECT  LISTITEM
                                                                          FROM    dbo.fnSplitter(@APACCOUNTS, @DELIMITER) )
                                                                          AND TRXDATE <= @ASOFDATE
                                                                  GROUP BY ORMSTRID ,
                                                                          ORTRXTYP ,
                                                                          ORDOCNUM ,
                                                                          JRNENTRY ,
                                                                          ORTRXSRC
                                                                  UNION ALL
                                                                  SELECT  'Open' AS DOCSTATUS ,
                                                                          ORMSTRID AS VENDORID ,
                                                                          CASE WHEN ORTRXTYP IN ( 2, 3 ) THEN 1
                                                                               ELSE ORTRXTYP
                                                                          END AS DOCUMENTTYPE ,
                                                                          CASE WHEN ORTRXTYP IN ( 2, 3 )
                                                                               THEN ( SELECT  VNDDOCNM
                                                                                      FROM    dbo.POP30300 A1
                                                                                      WHERE   A1.POPRCTNM = ORDOCNUM
                                                                                    )
                                                                               ELSE ORDOCNUM
                                                                          END AS DOCUMENTNUMBER ,
                                                                          JRNENTRY ,
                                                                          ORTRXSRC AS ORIGSOURCE ,
                                                                          SUM(DEBITAMT - CRDTAMNT) AS APAMOUNT
                                                                  FROM    dbo.GL30000
                                                                  WHERE   ACTINDX IN (
                                                                          SELECT  LISTITEM
                                                                          FROM    dbo.fnSplitter(@APACCOUNTS, @DELIMITER) )
                                                                          AND TRXDATE <= @ASOFDATE
                                                                  GROUP BY ORMSTRID ,
                                                                          ORTRXTYP ,
                                                                          ORDOCNUM ,
                                                                          JRNENTRY ,
                                                                          ORTRXSRC
                                                                  UNION ALL
                                                                  SELECT  'Work' AS DOCSTATUS ,
                                                                          A.ORMSTRID AS VENDORID ,
                                                                          CASE WHEN A.ORTRXTYP IN ( 2, 3 ) THEN 1
                                                                               ELSE A.ORTRXTYP
                                                                          END AS DOCUMENTTYPE ,
                                                                          CASE WHEN A.ORTRXTYP IN ( 2, 3 )
                                                                               THEN ( SELECT  VNDDOCNM
                                                                                      FROM    dbo.POP30300 A1
                                                                                      WHERE   A1.POPRCTNM = A.ORDOCNUM
                                                                                    )
                                                                               ELSE A.ORDOCNUM
                                                                          END AS DOCUMENTNUMBER ,
                                                                          A.JRNENTRY ,
                                                                          B.ORTRXSRC AS ORIGSOURCE ,
                                                                          SUM(A.DEBITAMT - A.CRDTAMNT) AS APAMOUNT
                                                                  FROM    dbo.GL10001 A
                                                                          INNER JOIN dbo.GL10000 B ON A.JRNENTRY = B.JRNENTRY
                                                                  WHERE   A.ACTINDX IN (
                                                                          SELECT  LISTITEM
                                                                          FROM    dbo.fnSplitter(@APACCOUNTS, @DELIMITER) )
                                                                          AND B.TRXDATE <= @ASOFDATE
                                                                          AND B.SERIES = 4
                                                                  GROUP BY A.ORMSTRID ,
                                                                          A.ORTRXTYP ,
                                                                          A.ORDOCNUM ,
                                                                          A.JRNENTRY ,
                                                                          B.ORTRXSRC
                                                                ) W
                                                      ) GL ON AP.MATCHKEY = GL.MATCHKEY
                            ) APRECON
                            INNER JOIN dbo.PM40102 DT ON APRECON.DOCTYPE = DT.DOCTYPE
                  ) AP
          UNION ALL
          ( SELECT  '' AS VENDORID ,
                    '' AS DOCNUMBR ,
                    ISNULL(CONVERT(VARCHAR(20), JRNENTRY), '') AS JRNENTRY ,
                    'GL Entry' AS DOCTYPE ,
                    ORTRXSRC AS AUDITTRAIL ,
                    0 AS SLAMOUNT ,
                    SUM(DEBITAMT - CRDTAMNT) AS GLAMOUNT ,
                    'Posted in GL, Not in SL' AS RECONSTATUS
            FROM    dbo.GL20000
            WHERE   ACTINDX IN ( SELECT LISTITEM
                                 FROM   dbo.fnSplitter(@APACCOUNTS, @DELIMITER) )
                    AND SERIES = 2
                    AND TRXDATE <= @ASOFDATE
            GROUP BY JRNENTRY ,
                    ORTRXSRC
          )
          UNION ALL
          ( SELECT  '' AS VENDORID ,
                    '' AS DOCNUMBR ,
                    ISNULL(CONVERT(VARCHAR(20), JRNENTRY), '') AS JRNENTRY ,
                    'GL Entry' AS DOCTYPE ,
                    ORTRXSRC AS AUDITTRAIL ,
                    0 AS SLAMOUNT ,
                    SUM(DEBITAMT - CRDTAMNT) AS GLAMOUNT ,
                    'Posted in GL, Not in SL' AS RECONSTATUS
            FROM    dbo.GL30000
            WHERE   ACTINDX IN ( SELECT LISTITEM
                                 FROM   dbo.fnSplitter(@APACCOUNTS, @DELIMITER) )
                    AND SERIES = 2
                    AND TRXDATE <= @ASOFDATE
            GROUP BY JRNENTRY ,
                    ORTRXSRC
          )
          UNION ALL
          ( SELECT  '' AS VENDORID ,
                    '' AS DOCNUMBR ,
                    ISNULL(CONVERT(VARCHAR(20), A.JRNENTRY), '') AS JRNENTRY ,
                    'GL Entry' AS DOCTYPE ,
                    B.ORTRXSRC AS AUDITTRAIL ,
                    0 AS SLAMOUNT ,
                    SUM(A.DEBITAMT - A.CRDTAMNT) AS GLAMOUNT ,
                    'Unposted in GL, Not in SL' AS RECONSTATUS
            FROM    dbo.GL10001 A
                    INNER JOIN dbo.GL10000 B ON A.JRNENTRY = B.JRNENTRY
            WHERE   A.ACTINDX IN ( SELECT LISTITEM
                                   FROM   dbo.fnSplitter(@APACCOUNTS, @DELIMITER) )
                    AND B.SERIES = 2
                    AND B.TRXDATE <= @ASOFDATE
            GROUP BY A.JRNENTRY ,
                    B.ORTRXSRC
          )
        ) APGL

Please create the function below which would be needed to execute the script above with multiple AP accounts specified. The AP accounts need to be provided as a string with the delimiter as specified in the code above.

/******************************************************************
Created Jan 17, 2012 by Sivakumar Venkataraman - Interdyn AKA
This function is to split the string passed with the delimiter
into a table which can be used as a sub query in other queries. 
 
Revision History
No.		Date			Description
1		03/07/2012		Original Version
*******************************************************************/
SET ANSI_NULLS ON
GO
 
SET QUOTED_IDENTIFIER ON
GO
 
CREATE FUNCTION [dbo].[fnSplitter]
       (
         @INPUTSTRING VARCHAR(8000) -- List of delimited items
         ,
         @DELIMITER VARCHAR(8000) = ',' -- delimiter that separates items
       )
RETURNS @LISTING TABLE ( LISTITEM VARCHAR(8000) )
  BEGIN
    DECLARE @LISTITEM VARCHAR(8000)
    WHILE CHARINDEX(@DELIMITER, @INPUTSTRING, 0) <> 0
          BEGIN
                SELECT  @LISTITEM = RTRIM(LTRIM(SUBSTRING(@INPUTSTRING, 1, CHARINDEX(@DELIMITER, @INPUTSTRING, 0) - 1))) ,
                        @INPUTSTRING = RTRIM(LTRIM(SUBSTRING(@INPUTSTRING,
                                                             CHARINDEX(@DELIMITER, @INPUTSTRING, 0) + LEN(@DELIMITER),
                                                             LEN(@INPUTSTRING))))
 
                IF LEN(@LISTITEM) > 0
                   INSERT INTO @LISTING
                          SELECT  @LISTITEM
          END
 
    IF LEN(@INPUTSTRING) > 0
       INSERT INTO @LISTING
              SELECT  @INPUTSTRING -- Put the last item in
    RETURN
  END
 
GO
 
GRANT SELECT ON fnSplitter TO DYNGRP

Currently this script works for a single payables account index. Will update the script to support multiple payable accounts soon.

Update 03/07/2012 – I have updated this script to support multiple AP account indexes.

Hope this helps the community…

Until next post!

VN:F [1.9.22_1171]
Rating: 0.0/10 (0 votes cast)
VN:F [1.9.22_1171]
Rating: +1 (from 1 vote)

Tags: , , , , , ,

Category: Accounts Payables, Dynamics, General Ledger, Great Plains, SQL Server, SQL Server 2005, SQL Server 2008

About the Author ()