Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Power BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.

Reply
DAXStudent
New Member

Help requested on Advanced DAX Problem

I have an advanced DAX problem that I need help with. I have 2 tables, Calendar and Transactions. The Calendar has a dynamic column named Relative Month that returns 0 for all dates in this month, -1 for all dates in last month, etc.

 

The transactions table looks like this:

 

Invoice IDDate of ServiceTransaction DateAmountAmount TypeDOSMonthDiff
12341/1/20241/1/2024100Invoice0
12341/1/20242/15/202450Payment-1
12341/1/20243/15/202425Payment-2
12341/1/20245/24/202425Payment-4
12352/1/20242/1/2024100Invoice0
12352/1/20243/14/202450Payment-1
12352/1/20245/31/202450Payment-3
12363/1/20243/1/2024100Invoice0
12363/1/20243/15/202450Payment0
12363/1/20247/1/202450Payment-4
12374/1/20244/15/2024100Invoice0
12374/1/20248/15/202450Payment-4
12374/1/202412/15/202450Payment-8
22343/1/20253/1/2025100Invoice0
22343/1/20254/15/202550Payment-1
22343/1/20255/15/202525Payment-2
22354/1/20254/1/2025100Invoice0
22354/1/20255/15/202550Payment-1
22365/1/20255/1/2025100Invoice0
22365/1/20255/15/202550Payment0
22376/1/20256/1/2025100Invoice0

 

As you can see Invoices and Payments are stacked vertically. DOSMonthDiff is the difference between the Transaction Date Month and the Date of Service Month.

 

The business wants me to summarize the data in 2 different views and then join the two dynamically.

 

First I need to pivot Payments and Invoices for Last Year by DOSMonthDiff with extra calcs, like this (done):

DAXStudent_1-1749355766977.png

 

Next I need to pivot this year's data by Month and relative month like this (done):

DAXStudent_0-1749355748741.png

Lastly I need to put the two together, with the measure "Payment Amount Divided by Whole Year Total - Last Year" joining DOSMonthDiff to Relative Month. This is what the solution should look like:

 

YearMonthRelative MonthInvoiced AmountPayment AmountPaymet Amount Divided by Whole Year Total - Last Year
Jun-250100 12.5%
May-25-11005025.0%
Apr-25-2100506.3%
Mar-25-31007512.5%

 

I must keep the current relationship between the calendar and the Transaction Table. The solution must be a DAX solution, not a Power Query solution. However you can introduce a new table(s) if needed. Ultimately the solution needs to be dynamic where "Payment Amount Divided by Whole Year Total - Last Year" always represents the year prior to the current year and where DOSMonthDiff is joined to Relative Month … even as time goes on, years change, relative month changes.

 

Download my pbix here:

https://www.dropbox.com/scl/fi/fdy5zodytrxz53hzb09mq/20250606-Advanced-DAX-Problem.pbix?rlkey=wvg26l...

 

3 REPLIES 3
v-sdhruv
Community Support
Community Support

Hi @DAXStudent ,
Just wanted to check if you had the opportunity to review the suggestions provided?
If the response has addressed your query, please accept it as a solution  so other members can easily find it.
Thank You

v-sdhruv
Community Support
Community Support

Hi @DAXStudent ,
Just wanted to check if you had the opportunity to review the suggestions provided?
If the response has addressed your query, please accept it as a solution  so other members can easily find it.
Thank You

Rupak_bi
Impactful Individual
Impactful Individual

Hi @DAXStudent ,

 

Here is your solution.

Rupak_bi_0-1749556246321.png

Steps:
1. Create a calculated column inthe transaction table

DOS-Relative Month Key = 
var Yr = year(Transactions[Date of Service])+1
var Mo = month(today())+Transactions[DOSMonthDiff]
Return
date(yr,mo,1)

2. Make an inactive relationship between the new column and calender date

Rupak_bi_1-1749556393535.png

3. Now Make a new Measure to use in the matrix

Payment Amount Divided by Whole Year Total - Last Year (New) = 

Var Current_Payment = CALCULATE([Payment Amount],USERELATIONSHIP('Calendar'[Date],Transactions[DOS-Relative Month Key]))
Var Total_Payment = CALCULATE([Payment Amount],ALL('Calendar'),'Calendar'[Year]=SELECTEDVALUE('Calendar'[Year])-1)

RETURN

CALCULATE(Current_Payment/Total_Payment,USERELATIONSHIP('Calendar'[Date],Transactions[DOS-Relative Month Key]))

 

Now make the table to get the desired result. 

Hope this will solve the purpose. If you want something more specific, let me know

Else Plz accept as solution.....



Regards
Rupak
FOLLOW ME : https://www.linkedin.com/in/rupaksar/

Helpful resources

Announcements
June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

Find out what's new and trending in the Fabric community.