Receivables HATB With Aging By Due Date (using Document Date)

Microsoft Dynamics GPToday’s script is an unusual one for me to post, as it is not a script which I have written; it is a script which returns the data for a Receivables HATB With Aging By Due Date (using Document Date). It was written by Sivakumar Venkataraman back in 2011 and came up in conversation recently; the site he posted it to no longer exists and I had to hunt the script out from the wayback machine to retrieve a copy.

The script is below is Siva’s script which I am reposting “as is” as it may be useful to others.

/******************************************************************
Created July 21, 2011 by Sivakumar Venkataraman - Interdyn AKA
This view is for the Receivables HATB for aging by due date and
picking transactions using the Document Date.
 
Tables used:
 - RM Open File Debit Copy (RM20101)
 - RM History File (RM30101)
 - RM Apply Open File (RM20201)
 - RM Apply History File (RM30201)
 - Document Type Setup File (RM40401)
 - RM Period Setup (RM40201)
 
Revision History
 No	 Date		Reason for Change
 1	 12/12/2017	Updated the logic for due date for credits
 ******************************************************************/
 
DECLARE @EMPTYDATE AS DATETIME
DECLARE @ASOFDATE AS DATETIME
 
SET @EMPTYDATE = '1900-01-01'
SET @ASOFDATE = '2017-04-12' 
 
SELECT  W.CUSTNMBR AS CUSTOMERNO ,
        W1.DOCDESCR AS DOCTYPE ,
        W.DOCNUMBR ,
        W.DOCDATE ,
        W.TRXSORCE ,
        W.GLPOSTDT AS POSTINGDATE ,
        W.DUEDATE ,
        W.AGINGBUCKET ,
        W.DOCUMENTAMT ,
        W.CURTRXAMT
FROM    ( SELECT    X.CUSTNMBR ,
                    X.RMDTYPAL ,
                    X.DOCNUMBR ,
                    X.DOCDATE ,
                    X.TRXSORCE ,
                    X.VOIDED ,
                    X.GLPOSTDT ,
                    X.DUEDATE ,
                    X.DAYSDUE ,
                    CASE WHEN X.DAYSDUE > 999 THEN ( SELECT TOP 1
                                                            RMPERDSC
                                                     FROM   dbo.RM40201
                                                     ORDER BY RMPEREND DESC
                                                   )
                         WHEN X.DAYSDUE < 0 THEN 'Not Due'
                         ELSE ISNULL(( SELECT TOP 1
                                                RMPERDSC
                                       FROM     dbo.RM40201 AG
                                       WHERE    X.DAYSDUE <= AG.RMPEREND
                                       ORDER BY RMPEREND
                                     ), '')
                    END AS AGINGBUCKET ,
                    X.VOIDPDATE ,
                    X.DOCUMENTAMT ,
                    X.APPLIEDAMT ,
                    X.WRITEOFFAMT ,
                    X.DISCTAKENAMT ,
                    X.REALGAINLOSSAMT ,
                    CASE WHEN X.RMDTYPAL < 6
                         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.CUSTNMBR ,
                                Z.RMDTYPAL ,
                                Z.DOCDATE ,
                                Z.DOCNUMBR ,
                                Z.ORTRXAMT AS DOCUMENTAMT ,
                                CASE WHEN RMDTYPAL < 6 THEN ISNULL(( SELECT SUM(Y.APPLDAMT)
                                                                     FROM   ( SELECT    CUSTNMBR ,
                                                                                        APFRDCDT ,
                                                                                        DATE1 ,
                                                                                        APTODCNM ,
                                                                                        APTODCTY ,
                                                                                        APFRDCNM ,
                                                                                        APFRDCTY ,
                                                                                        APPTOAMT AS APPLDAMT
                                                                              FROM      dbo.RM20201
                                                                              WHERE     POSTED = 1
                                                                                        AND APTODCTY <> 6
                                                                              UNION
                                                                              SELECT    CUSTNMBR ,
                                                                                        APFRDCDT ,
                                                                                        DATE1 ,
                                                                                        APTODCNM ,
                                                                                        APTODCTY ,
                                                                                        APFRDCNM ,
                                                                                        APFRDCTY ,
                                                                                        APPTOAMT AS APPLDAMT
                                                                              FROM      dbo.RM30201
                                                                              WHERE     APTODCTY <> 6
                                                                            ) Y
                                                                     WHERE  Y.DATE1 <= @ASOFDATE
                                                                            AND Y.APFRDCDT <= @ASOFDATE
                                                                            AND Y.APFRDCDT <> @EMPTYDATE
                                                                            AND Y.CUSTNMBR = Z.CUSTNMBR
                                                                            AND Y.APTODCNM = Z.DOCNUMBR
                                                                            AND Y.APTODCTY = Z.RMDTYPAL
                                                                   ), 0)
                                     WHEN RMDTYPAL > 6
                                          AND RMDTYPAL <= 9 THEN ISNULL(( SELECT    SUM(Y.APPLDAMT)
                                                                          FROM      ( SELECT    CUSTNMBR ,
                                                                                                DATE1 ,
                                                                                                APPTOAMT AS APPLDAMT ,
                                                                                                APFRDCNM ,
                                                                                                APFRDCTY ,
                                                                                                APTODCNM ,
                                                                                                APTODCTY ,
                                                                                                APTODCDT
                                                                                      FROM      dbo.RM20201
                                                                                      WHERE     POSTED = 1
                                                                                                AND APTODCTY <> 6
                                                                                      UNION
                                                                                      SELECT    CUSTNMBR ,
                                                                                                DATE1 ,
                                                                                                APPTOAMT ,
                                                                                                APFRDCNM ,
                                                                                                APFRDCTY ,
                                                                                                APTODCNM ,
                                                                                                APTODCTY ,
                                                                                                APTODCDT
                                                                                      FROM      dbo.RM30201
                                                                                      WHERE     APTODCTY <> 6
                                                                                    ) Y
                                                                          WHERE     Y.DATE1 <= @ASOFDATE
                                                                                    AND Y.APTODCDT <= @ASOFDATE
                                                                                    AND Y.APTODCDT <> @EMPTYDATE
                                                                                    AND Y.CUSTNMBR = Z.CUSTNMBR
                                                                                    AND Y.APFRDCNM = Z.DOCNUMBR
                                                                                    AND Y.APFRDCTY = Z.RMDTYPAL
                                                                        ), 0)
                                     ELSE 0
                                END AS APPLIEDAMT ,
                                CASE WHEN RMDTYPAL < 6 THEN ISNULL(( SELECT SUM(Y.WROFAMNT)
                                                                     FROM   ( SELECT    CUSTNMBR ,
                                                                                        APFRDCDT ,
                                                                                        DATE1 ,
                                                                                        APTODCNM ,
                                                                                        APTODCTY ,
                                                                                        APFRDCNM ,
                                                                                        APFRDCTY ,
                                                                                        WROFAMNT
                                                                              FROM      dbo.RM20201
                                                                              WHERE     POSTED = 1
                                                                                        AND APTODCTY <> 6
                                                                              UNION
                                                                              SELECT    CUSTNMBR ,
                                                                                        APFRDCDT ,
                                                                                        DATE1 ,
                                                                                        APTODCNM ,
                                                                                        APTODCTY ,
                                                                                        APFRDCNM ,
                                                                                        APFRDCTY ,
                                                                                        WROFAMNT
                                                                              FROM      dbo.RM30201
                                                                              WHERE     APTODCTY <> 6
                                                                            ) Y
                                                                     WHERE  Y.DATE1 <= @ASOFDATE
                                                                            AND Y.APFRDCDT <= @ASOFDATE
                                                                            AND Y.APFRDCDT <> @EMPTYDATE
                                                                            AND Y.CUSTNMBR = Z.CUSTNMBR
                                                                            AND Y.APTODCNM = Z.DOCNUMBR
                                                                            AND Y.APTODCTY = Z.RMDTYPAL
                                                                   ), 0)
                                     ELSE 0
                                END AS WRITEOFFAMT ,
                                CASE WHEN RMDTYPAL < 6 THEN ISNULL(( SELECT SUM(Y.DISTKNAM)
                                                                     FROM   ( SELECT    CUSTNMBR ,
                                                                                        APFRDCDT ,
                                                                                        DATE1 ,
                                                                                        APTODCNM ,
                                                                                        APTODCTY ,
                                                                                        APFRDCNM ,
                                                                                        APFRDCTY ,
                                                                                        DISTKNAM
                                                                              FROM      dbo.RM20201
                                                                              WHERE     POSTED = 1
                                                                                        AND APTODCTY <> 6
                                                                              UNION
                                                                              SELECT    CUSTNMBR ,
                                                                                        APFRDCDT ,
                                                                                        DATE1 ,
                                                                                        APTODCNM ,
                                                                                        APTODCTY ,
                                                                                        APFRDCNM ,
                                                                                        APFRDCTY ,
                                                                                        DISTKNAM
                                                                              FROM      dbo.RM30201
                                                                              WHERE     APTODCTY <> 6
                                                                            ) Y
                                                                     WHERE  Y.DATE1 <= @ASOFDATE
                                                                            AND Y.APFRDCDT <= @ASOFDATE
                                                                            AND Y.APFRDCDT <> @EMPTYDATE
                                                                            AND Y.CUSTNMBR = Z.CUSTNMBR
                                                                            AND Y.APTODCNM = Z.DOCNUMBR
                                                                            AND Y.APTODCTY = Z.RMDTYPAL
                                                                   ), 0)
                                     ELSE 0
                                END AS DISCTAKENAMT ,
                                CASE WHEN RMDTYPAL > 6 THEN ISNULL(( SELECT SUM(Y.RLGANLOS)
                                                                     FROM   ( SELECT    CUSTNMBR ,
                                                                                        DATE1 ,
                                                                                        APFRDCNM ,
                                                                                        APFRDCTY ,
                                                                                        APTODCNM ,
                                                                                        APTODCTY ,
                                                                                        APTODCDT ,
                                                                                        RLGANLOS
                                                                              FROM      dbo.RM20201
                                                                              WHERE     POSTED = 1
                                                                                        AND APTODCTY <> 6
                                                                              UNION
                                                                              SELECT    CUSTNMBR ,
                                                                                        DATE1 ,
                                                                                        APFRDCNM ,
                                                                                        APFRDCTY ,
                                                                                        APTODCNM ,
                                                                                        APTODCTY ,
                                                                                        APTODCDT ,
                                                                                        RLGANLOS
                                                                              FROM      dbo.RM30201
                                                                              WHERE     APTODCTY <> 6
                                                                            ) Y
                                                                     WHERE  Y.DATE1 <= @ASOFDATE
                                                                            AND Y.APTODCDT <= @ASOFDATE
                                                                            AND Y.APTODCDT <> @EMPTYDATE
                                                                            AND Y.CUSTNMBR = Z.CUSTNMBR
                                                                            AND Y.APFRDCNM = Z.DOCNUMBR
                                                                            AND Y.APFRDCTY = Z.RMDTYPAL
                                                                   ), 0)
                                     ELSE 0
                                END AS REALGAINLOSSAMT ,
                                Z.TRXSORCE ,
                                Z.VOIDED ,
                                Z.GLPOSTDT ,
                                Z.DUEDATE ,
                                DATEDIFF(dd, Z.DUEDATE, @ASOFDATE) AS DAYSDUE ,
                                Z.VOIDPDATE
                      FROM      ( SELECT    CUSTNMBR ,
                                            RMDTYPAL ,
                                            DOCDATE ,
                                            DOCNUMBR ,
                                            ORTRXAMT ,
                                            BACHNUMB ,
                                            TRXSORCE ,
                                            BCHSOURC ,
                                            DISCDATE ,
                                            VOIDSTTS AS VOIDED ,
                                            GLPOSTDT ,
                                            CASE WHEN DUEDATE = @EMPTYDATE THEN DOCDATE
                                                 ELSE [DUEDATE]
                                            END AS DUEDATE ,
                                            VOIDDATE AS VOIDPDATE
                                  FROM      dbo.RM20101
                                  UNION
                                  SELECT    CUSTNMBR ,
                                            RMDTYPAL ,
                                            DOCDATE ,
                                            DOCNUMBR ,
                                            ORTRXAMT ,
                                            BACHNUMB ,
                                            TRXSORCE ,
                                            BCHSOURC ,
                                            DISCDATE ,
                                            VOIDSTTS AS VOIDED ,
                                            GLPOSTDT ,
                                            CASE WHEN DUEDATE = @EMPTYDATE THEN DOCDATE
                                                 ELSE [DUEDATE]
                                            END AS DUEDATE ,
                                            VOIDDATE AS VOIDPDATE
                                  FROM      dbo.RM30101
                                ) Z
                      WHERE     Z.DOCDATE <= @ASOFDATE
                                AND Z.VOIDED = 0
                                AND Z.RMDTYPAL <> 6
                    ) X
          UNION ALL
          SELECT    X.CUSTNMBR ,
                    X.RMDTYPAL ,
                    X.DOCNUMBR ,
                    X.DOCDATE ,
                    X.TRXSORCE ,
                    X.VOIDED ,
                    X.PSTGDATE ,
                    X.DUEDATE ,
                    X.DAYSDUE ,
                    CASE WHEN X.DAYSDUE > 999 THEN ( SELECT TOP 1
                                                            RMPERDSC
                                                     FROM   dbo.RM40201
                                                     ORDER BY RMPEREND DESC
                                                   )
                         WHEN X.DAYSDUE < 0 THEN 'Not Due'
                         ELSE ISNULL(( SELECT TOP 1
                                                RMPERDSC
                                       FROM     dbo.RM40201 AG
                                       WHERE    X.DAYSDUE <= AG.RMPEREND
                                       ORDER BY RMPEREND
                                     ), '')
                    END AS AGINGBUCKET ,
                    X.VOIDPDATE ,
                    X.DOCUMENTAMT ,
                    X.APPLIEDAMT ,
                    X.WRITEOFFAMT ,
                    X.DISCTAKENAMT ,
                    X.REALGAINLOSSAMT ,
                    CASE WHEN X.RMDTYPAL < 6
                         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.CUSTNMBR ,
                                Z.RMDTYPAL ,
                                Z.DOCDATE ,
                                Z.DOCNUMBR ,
                                Z.ORTRXAMT AS DOCUMENTAMT ,
                                CASE WHEN RMDTYPAL < 6 THEN ISNULL(( SELECT SUM(Y.APPLDAMT)
                                                                     FROM   ( SELECT    CUSTNMBR ,
                                                                                        APFRDCDT ,
                                                                                        DATE1 ,
                                                                                        APTODCNM ,
                                                                                        APTODCTY ,
                                                                                        APFRDCNM ,
                                                                                        APFRDCTY ,
                                                                                        APPTOAMT AS APPLDAMT
                                                                              FROM      dbo.RM20201
                                                                              WHERE     POSTED = 1
                                                                                        AND APTODCTY <> 6
                                                                              UNION
                                                                              SELECT    CUSTNMBR ,
                                                                                        APFRDCDT ,
                                                                                        DATE1 ,
                                                                                        APTODCNM ,
                                                                                        APTODCTY ,
                                                                                        APFRDCNM ,
                                                                                        APFRDCTY ,
                                                                                        APPTOAMT AS APPLDAMT
                                                                              FROM      dbo.RM30201
                                                                              WHERE     APTODCTY <> 6
                                                                            ) Y
                                                                     WHERE  Y.DATE1 <= @ASOFDATE
                                                                            AND Y.APFRDCDT <= @ASOFDATE
                                                                            AND Y.APFRDCDT <> @EMPTYDATE
                                                                            AND Y.CUSTNMBR = Z.CUSTNMBR
                                                                            AND Y.APTODCNM = Z.DOCNUMBR
                                                                            AND Y.APTODCTY = Z.RMDTYPAL
                                                                   ), 0)
                                     WHEN RMDTYPAL > 6
                                          AND RMDTYPAL <= 9 THEN ISNULL(( SELECT    SUM(Y.APPLDAMT)
                                                                          FROM      ( SELECT    CUSTNMBR ,
                                                                                                DATE1 ,
                                                                                                APPTOAMT AS APPLDAMT ,
                                                                                                APFRDCNM ,
                                                                                                APFRDCTY ,
                                                                                                APTODCNM ,
                                                                                                APTODCTY ,
                                                                                                APTODCDT
                                                                                      FROM      dbo.RM20201
                                                                                      WHERE     POSTED = 1
                                                                                                AND APTODCTY <> 6
                                                                                      UNION
                                                                                      SELECT    CUSTNMBR ,
                                                                                                DATE1 ,
                                                                                                APPTOAMT ,
                                                                                                APFRDCNM ,
                                                                                                APFRDCTY ,
                                                                                                APTODCNM ,
                                                                                                APTODCTY ,
                                                                                                APTODCDT
                                                                                      FROM      dbo.RM30201
                                                                                      WHERE     APTODCTY <> 6
                                                                                    ) Y
                                                                          WHERE     Y.DATE1 <= @ASOFDATE
                                                                                    AND Y.APTODCDT <= @ASOFDATE
                                                                                    AND Y.APTODCDT <> @EMPTYDATE
                                                                                    AND Y.CUSTNMBR = Z.CUSTNMBR
                                                                                    AND Y.APFRDCNM = Z.DOCNUMBR
                                                                                    AND Y.APFRDCTY = Z.RMDTYPAL
                                                                        ), 0)
                                     ELSE 0
                                END AS APPLIEDAMT ,
                                CASE WHEN RMDTYPAL < 6 THEN ISNULL(( SELECT SUM(Y.WROFAMNT)
                                                                     FROM   ( SELECT    CUSTNMBR ,
                                                                                        APFRDCDT ,
                                                                                        DATE1 ,
                                                                                        APTODCNM ,
                                                                                        APTODCTY ,
                                                                                        APFRDCNM ,
                                                                                        APFRDCTY ,
                                                                                        WROFAMNT
                                                                              FROM      dbo.RM20201
                                                                              WHERE     POSTED = 1
                                                                                        AND APTODCTY <> 6
                                                                              UNION
                                                                              SELECT    CUSTNMBR ,
                                                                                        APFRDCDT ,
                                                                                        DATE1 ,
                                                                                        APTODCNM ,
                                                                                        APTODCTY ,
                                                                                        APFRDCNM ,
                                                                                        APFRDCTY ,
                                                                                        WROFAMNT
                                                                              FROM      dbo.RM30201
                                                                              WHERE     APTODCTY <> 6
                                                                            ) Y
                                                                     WHERE  Y.DATE1 <= @ASOFDATE
                                                                            AND Y.APFRDCDT <= @ASOFDATE
                                                                            AND Y.APFRDCDT <> @EMPTYDATE
                                                                            AND Y.CUSTNMBR = Z.CUSTNMBR
                                                                            AND Y.APTODCNM = Z.DOCNUMBR
                                                                            AND Y.APTODCTY = Z.RMDTYPAL
                                                                   ), 0)
                                     ELSE 0
                                END AS WRITEOFFAMT ,
                                CASE WHEN RMDTYPAL < 6 THEN ISNULL(( SELECT SUM(Y.DISTKNAM)
                                                                     FROM   ( SELECT    CUSTNMBR ,
                                                                                        APFRDCDT ,
                                                                                        DATE1 ,
                                                                                        APTODCNM ,
                                                                                        APTODCTY ,
                                                                                        APFRDCNM ,
                                                                                        APFRDCTY ,
                                                                                        DISTKNAM
                                                                              FROM      dbo.RM20201
                                                                              WHERE     POSTED = 1
                                                                                        AND APTODCTY <> 6
                                                                              UNION
                                                                              SELECT    CUSTNMBR ,
                                                                                        APFRDCDT ,
                                                                                        DATE1 ,
                                                                                        APTODCNM ,
                                                                                        APTODCTY ,
                                                                                        APFRDCNM ,
                                                                                        APFRDCTY ,
                                                                                        DISTKNAM
                                                                              FROM      dbo.RM30201
                                                                              WHERE     APTODCTY <> 6
                                                                            ) Y
                                                                     WHERE  Y.DATE1 <= @ASOFDATE
                                                                            AND Y.APFRDCDT <= @ASOFDATE
                                                                            AND Y.APFRDCDT <> @EMPTYDATE
                                                                            AND Y.CUSTNMBR = Z.CUSTNMBR
                                                                            AND Y.APTODCNM = Z.DOCNUMBR
                                                                            AND Y.APTODCTY = Z.RMDTYPAL
                                                                   ), 0)
                                     ELSE 0
                                END AS DISCTAKENAMT ,
                                CASE WHEN RMDTYPAL > 6 THEN ISNULL(( SELECT SUM(Y.RLGANLOS)
                                                                     FROM   ( SELECT    CUSTNMBR ,
                                                                                        DATE1 ,
                                                                                        APFRDCNM ,
                                                                                        APFRDCTY ,
                                                                                        APTODCNM ,
                                                                                        APTODCTY ,
                                                                                        APTODCDT ,
                                                                                        RLGANLOS
                                                                              FROM      dbo.RM20201
                                                                              WHERE     POSTED = 1
                                                                                        AND APTODCTY <> 6
                                                                              UNION
                                                                              SELECT    CUSTNMBR ,
                                                                                        DATE1 ,
                                                                                        APFRDCNM ,
                                                                                        APFRDCTY ,
                                                                                        APTODCNM ,
                                                                                        APTODCTY ,
                                                                                        APTODCDT ,
                                                                                        RLGANLOS
                                                                              FROM      dbo.RM30201
                                                                              WHERE     APTODCTY <> 6
                                                                            ) Y
                                                                     WHERE  Y.DATE1 <= @ASOFDATE
                                                                            AND Y.APTODCDT <= @ASOFDATE
                                                                            AND Y.APTODCDT <> @EMPTYDATE
                                                                            AND Y.CUSTNMBR = Z.CUSTNMBR
                                                                            AND Y.APFRDCNM = Z.DOCNUMBR
                                                                            AND Y.APFRDCTY = Z.RMDTYPAL
                                                                   ), 0)
                                     ELSE 0
                                END AS REALGAINLOSSAMT ,
                                Z.TRXSORCE ,
                                Z.VOIDED ,
                                Z.PSTGDATE ,
                                Z.DUEDATE ,
                                DATEDIFF(dd, Z.DUEDATE, @ASOFDATE) AS DAYSDUE ,
                                Z.VOIDPDATE
                      FROM      ( SELECT    CUSTNMBR ,
                                            RMDTYPAL ,
                                            DOCDATE ,
                                            DOCNUMBR ,
                                            ORTRXAMT ,
                                            BACHNUMB ,
                                            TRXSORCE ,
                                            BCHSOURC ,
                                            DISCDATE ,
                                            VOIDSTTS AS VOIDED ,
                                            GLPOSTDT AS PSTGDATE ,
                                            CASE WHEN DUEDATE = @EMPTYDATE THEN DOCDATE
                                                 ELSE [DUEDATE]
                                            END AS DUEDATE ,
                                            VOIDDATE AS VOIDPDATE
                                  FROM      dbo.RM20101
                                  UNION
                                  SELECT    CUSTNMBR ,
                                            RMDTYPAL ,
                                            DOCDATE ,
                                            DOCNUMBR ,
                                            ORTRXAMT ,
                                            BACHNUMB ,
                                            TRXSORCE ,
                                            BCHSOURC ,
                                            DISCDATE ,
                                            VOIDSTTS AS VOIDED ,
                                            GLPOSTDT ,
                                            CASE WHEN DUEDATE = @EMPTYDATE THEN DOCDATE
                                                 ELSE [DUEDATE]
                                            END AS DUEDATE ,
                                            VOIDDATE AS VOIDPDATE
                                  FROM      dbo.RM30101
                                ) Z
                      WHERE     Z.DOCDATE <= @ASOFDATE
                                AND Z.VOIDED = 1
                                AND Z.RMDTYPAL <> 6
                                AND Z.VOIDPDATE > @ASOFDATE
                    ) X
        ) W
        INNER JOIN dbo.RM40401 W1 ON W.RMDTYPAL = W1.RMDTYPAL
WHERE   W.CURTRXAMT <> 0

Recent ISC Software Webinar: Automation in Microsoft Dynamics GP

ISC Software SolutionsIn our most recent webinar, we took a look at Automation in Microsoft Dynamics GP. In this webinar, we covered how automation can be used in Microsoft Dynamics GP to improve efficiencies and accuracy of data. If you want to catch up on this, or any other, webinar, you can do so here.

In this blog post, I am going to recap the webinar and cover the highlights of how automation can be used in Microsoft Dynamics GP to improve efficiencies and improve data accuracy:

  1. Introduction
  2. Integration
  3. Scanning
  4. Approval
  5. Posting
  6. Reporting
  7. Conclusion

Introduction ^

Where possible in this webinar I highlighted standard, or Microsoft supplied, features or additional products where they are available. However, in many cases the standard functionality does not allow for full automation. This is an intentional design choice made when Microsoft Dynamics GP was first created back in the md-90s. The company who created Great Plains, the original name of Dynamics GP, was intended from the very beginning to be extensible with the intention that there be a thriving third-party marketplace for add-ons.

This is the current situation; the core Dynamics GP system has strong core financials and distribution modules, but wider functionality is provided by third party (Independent Software Vendors (ISVs) who have a variety of add-ons and complimentary products which provide the functionality required or automating processes. In each of the areas, there are usually a number of products available from several vendors, but I have selected one in each area. usually an add-on which I have used with several clients across a number of years and which has received positive reviews.

Before implementing one of the solutions, I’d recommend reviewing the functionality it includes, the functionality of competing products and making your own decision about which will best fit your requirements.

Continue reading “Recent ISC Software Webinar: Automation in Microsoft Dynamics GP”

azurecurve ClassicPress Plugins: SMTP

ClassicPress PluginsThis is part of the azurecurve ClassicPress Plugins which introduces the plugins I have available for ClassicPress.

The plugin I am going to cover in this post, is a brand new one written for ClassicPress; SMTP.

Functionality

Simple Mail Transport Protocol (SMTP) plugin will intercept the standard wp_mail and send emails via an SMTP server using PHPMAILER.

This plugin is multisite compatible; each site will need settings to be configured in the admin dashboard.

Download

The plugin can be downloaded via my Development site.

Click to show/hide the azurecurve ClassicPress Plugins Series Index

azurecurve ClassicPress Plugins: Maintenance Mode

ClassicPress PluginsThis is part of the azurecurve ClassicPress Plugins which introduces the plugins I have available for ClassicPress.

The plugin I am going to cover in this post, is a brand new one written for ClassicPress; Maintenance Mode.

Functionality

Enable maintenance mode to disable the front-end of your ClassicPress site for non-administrators.

Users will only see the configured message; administrators will have full access to the site, but a prominent configurable warning that maintenance mode is enabled will be displayed at the top of every page.

This plugin is multisite compatible with each site having its own settings.

Download

The plugin can be downloaded via my Development site.

Click to show/hide the azurecurve ClassicPress Plugins Series Index

Outlook Not Sending Emails

Microsoft OutlookWe recently had anew consultant join us at ISC Software which meant building a new laptop. As she lives fairly near me the laptop and other kit was delivered to me and I did some setup. Once she was logged on there was one unexpected issue with emails not sending in Outlook.

I did some checking of settings and found that there is a setting which needed to be enabled for sending of emails; I’m not sure why it was not set as I don’t recall having set it previously.

The setting is in (File » Options); select the Advanced tab and, under Send and receive, mark the Send immediately when connected checkbox:

Outlook Options

Once the options were saved, emails were correctly sending.

Using No-IP For External Access With a Dynamics IP Address: Installing No-IP Client

Useful ApplicationsThis post is part of the short series on using Using No-IP For External Access With a Dynamics IP Address.

With a No-IP account created with No-IP the next, and final, step is to install the Dynamic DNS Update Client. This does updates on a paeriodic basis to keep your current IP address in sync with your No-IP host or domain.

The client can be downloaded from here:

Download client

Continue reading “Using No-IP For External Access With a Dynamics IP Address: Installing No-IP Client”

Using No-IP For External Access With a Dynamics IP Address: Creating An Account

Useful ApplicationsThis post is part of the short series on using Using No-IP For External Access With a Dynamics IP Address.

Signing up to No-IP for a free account is nice and easy to do. Using the browser of your choice, navigate to https://www.noip.com, enter the hostname you want and select the domain from the list of free ones and click the green ,em>Sign Up button:

Sign Up

Continue reading “Using No-IP For External Access With a Dynamics IP Address: Creating An Account”

azurecurve ClassicPress Plugins: Update Admin Menu

ClassicPress PluginsThis is part of the azurecurve ClassicPress Plugins which introduces the plugins I have available for ClassicPress.

The plugin I am going to cover in this post, is a brand new one written for ClassicPress; Update Admin Menu.

Functionality

Allows the reorganisation of the ClassicPress admin menu allowing you to move more often used menu entries to the top of the menu.

Download

The plugin can be downloaded via my Development site.

Click to show/hide the azurecurve ClassicPress Plugins Series Index

azurecurve ClassicPress Plugins: From Twitter

ClassicPress PluginsThis is part of the azurecurve ClassicPress Plugins which introduces the plugins I have available for ClassicPress.

The plugin I am going to cover in this post, is a brand new one written for ClassicPress; From Twitter.

Functionality

Automate the retrieval of tweets from Twitter and create posts on your ClassicPress site

From Twitter includes the following functionality;

  • Search Twitter and create tweets as posts or as a Tweet custom post type.
  • Specify the title and content in posts for retrieved tweets.
  • Choose whether to save tweet data.
  • Choose cron frequency (hourly, twice daily or daily).
  • Choose how many tweets to return each time the cron runs (max 100 as per Twitter api).
  • Choose whether Tweet images should be downloaded.

Make sure that once all the settings have been configured, you enable the cron job to run on the Cron Settings tab.

Download

The plugin can be downloaded via my Development site.

Click to show/hide the azurecurve ClassicPress Plugins Series Index

Using No-IP For External Access With a Dynamics IP Address: What Is No-IP?

Useful ApplicationsThis post is part of the short series on using Using No-IP For External Access With a Dynamics IP Address.

No-IP is a service which has been around for quite a long time now (I remember using a competitor of theirs back in 2004 (and possibly earlier) to use an external DNS entry to access a web server I was running at home on a dynamic IP address (my ISP at the time didn’t offer static IP addresses and I didn’t sign up for one wit my current provider).

No-IP as a company have several offerings, but the one I am looking at in this series is the Free Dynamic DNS offering which allows for 3 hostnames on a limited set of domains and requires you to confirm the DNS every 30 days. There are two paid offering with more hostnames, domains and which do not expire, but I only need one hostname so the free option is sufficient and I don’t mind clicking a link on an email to renew every 30 days.

As well as my use case of remotely accessing a NAS or computer, No-IP can allow you to access any Internet enabled device on your home network even when you have a dynamic IP address (if you have a static IP then you could connect just using the IP address, although using a hostname is easier to remember); there may be configuration required on your router to forward ports to the devices on your network.

I’ve also had my dad sign up and install No-IP so I can easily access his system remotely to help out with any problems he is having.