AP Automation in Dynamics 365 Finance and Supply Chain

As a solution architect, prospects and clients often ask me for ways to improve their Accounts Payable process.  They receive hundreds of invoices every month, and it can take considerable amount of time to enter all of the detail as well as attaching the invoice for reference during the approval process.  This is an area where we have often needed to bring in an ISV solution, but that could cause other issues.  Microsoft has been doing considerable work around automation for AP and they recently released a public preview of their Invoice Capture solution. I have had the opportunity to set this up in one of my test environments so I could get an idea of what they have to offer.  As we would expect, the Invoice Capture solution is built on the Power Platform.  It uses a model driven Power App along with Power Automate Flows to integrate with Dynamics 365 Finance.  However, since it is a solution, they have done much of the work for you, including creating the standard flows to load the

Showing the last 12 months based on a date slicer

When working with financial and sales data, clients often ask for charts showing the last 12 months of data.  This is actually very simple using relative date filtering.




In addition, they might ask to compare to the same month last year.  With a simple DAX calculation (SAMEPERIODLASTYEAR) it is possible to add this measure.

Here is the formula:

Same Month Last Year = CALCULATE(Sum(Sales[SalesAmount]),SAMEPERIODLASTYEAR('Date'[Datekey]))









For many users this is all they need.  The chart will update each month and they will always be able to see the last 12 months.  










However, this chart will not work with date slicers.  If the client adds a date slicer to the page and selects just one month, the chart will be limited to one month.


The reason the chart is limited to one month is because the date dimension relates to the sales fact table and it filters the data for the selected month.

However, this is not what the users want.  They would prefer to see rolling 12 months based on the selected month like below.




Configuring the data model for user selected rolling 12 month reporting

Step 1: Create two tables, Table 1 is Year and Table 2 is Month.  These tables will not relate to any of the other tables in the data model.
           
a.     From the Home Ribbon chose Enter Data

b.     Create a Year table with one column (Year)

c.     Create a Month table with two columns (Month #, Month)  (Month # can be used to sort the month names in the proper order)


Step 2: Create two new measures: Current Month Sales and Same Month Last Year Sales
Current Month Sales1 =
var Ldate = date(max('Year'[Year]),max('Month'[Month #]),1) //Last date
var Fdate = EDATE(Ldate,-11) //First date
var SumSales = Sum(Sales[SalesAmount]) //Calculation
return
 if(min('Date'[Datekey])<fdate,
         blank(),
         if(min('Date'[Datekey])>Ldate,
                   blank(),
                   SumSales))

Same Month Last Year Sales1 =
var Ldate = date(max('Year'[Year]),max('Month'[Month #]),1) //Last date
var Fdate = EDATE(Ldate,-11) //First date
var SumSales = CALCULATE(Sum(Sales[SalesAmount]), Sameperiodlastyear('Date'[Datekey])) //Calculation
return
 if(min('Date'[Datekey])<fdate,
         blank(),
         if(min('Date'[Datekey])>Ldate,
                   blank(),

                   SumSales))

Step 3: Create a chart using the two new measures with an axis for the month from the date dimension.  Add two slicers on the report from the Year and Month tables created in the step 1.

Summary

This approach can be used with an entire report as well.  Simply create additional measures as needed.  In addition if you would prefer six months or three months, then simply update the formula by replacing -11 with -5 or -2.


Comments

  1. Hey Dan! I saw a post of yours on the PUG forums and found this blog very useful. I was able to set this up in my datasets, but having issues adding in additional metrics (i'm fairly new to Power BI and DAX). I'd love to view these in table form and add in things like YTD metrics, similar to your last picture. Any suggestions or tips you could provide?

    ReplyDelete
    Replies
    1. Tyler, since you are a member of PUG, you can actually download the PBIX file I used to create that screenshot as it was part of my Visualization session at the World Tour. It is in the World Tour library under the San Francisco chapter. Here is the link https://www.pbiusergroup.com/viewdocument/data-visualization-best-practices-f-2?CommunityKey=bcc3773c-8717-4a25-9bfe-8c2deddf60ea&tab=librarydocuments

      Let me know if you have trouble accessing it.

      Delete
    2. Thank you so much Dan! It looks like my original PY YTD measure wasn't calculated correctly. That helped a lot. Thanks again!

      Delete

Post a Comment

Popular posts from this blog

Creating a date table with a fiscal year in your Power BI data model

Adding a new entity to Dual-write in Dynamics 365 Finance