Get certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now
Hi everyone!
I have weekly revenue data for 3 lines of business, and I am trying to calculate for each line of business what the change in revenue is week-to-week. I suspect that I could do this by splitting the data into 3 tables (one per Line of Business), but I would rather keep the data together in one table to simplify the model.
Below is my sample (dummy) data:
Week | Line_Of_Business | Opportunity_Revenue |
8/12/2019 | A | 123 |
8/12/2019 | B | 456 |
8/12/2019 | C | 789 |
8/19/2019 | A | 120 |
8/19/2019 | B | 446 |
8/19/2019 | C | 782 |
8/26/2019 | A | 131 |
8/26/2019 | B | 445 |
8/26/2019 | C | 788 |
9/2/2019 | A | 125 |
9/2/2019 | B | 455 |
9/2/2019 | C | 800 |
9/9/2019 | A | 134 |
9/9/2019 | B | 446 |
9/9/2019 | C | 800 |
9/16/2019 | A | 137 |
9/16/2019 | B | 446 |
9/16/2019 | C | 803 |
Right now, I am using the following DAX to calculate the Previous_Week_Revenue for each Line of Business:
Previous_Week_Revenue =
VAR Pre_date =
CALCULATE (
MAX ( 'Sales Pipeline'[Week] ),
'Sales Pipeline',
'Sales Pipeline'[Week] < EARLIER ( 'Sales Pipeline'[Week] )
)
RETURN
CALCULATE (
SUM ( 'Sales Pipeline'[Opportunity Revenue] ),
'Sales Pipeline',
'Sales Pipeline'[Week] = Pre_date
)
However, this code is giving me the total revenue per week, rather than for the particular line of business.
Current Result:
Week | Line_Of_Business | Opportunity_Revenue | Previous_Week_Revenue |
8/12/2019 | A | 123 | |
8/12/2019 | B | 456 | |
8/12/2019 | C | 789 | |
8/19/2019 | A | 120 | 1368 |
8/19/2019 | B | 446 | 1368 |
8/19/2019 | C | 782 | 1368 |
8/26/2019 | A | 131 | 1348 |
8/26/2019 | B | 445 | 1348 |
8/26/2019 | C | 788 | 1348 |
9/2/2019 | A | 125 | 1364 |
9/2/2019 | B | 455 | 1364 |
9/2/2019 | C | 800 | 1364 |
9/9/2019 | A | 134 | 1380 |
9/9/2019 | B | 446 | 1380 |
9/9/2019 | C | 800 | 1380 |
9/16/2019 | A | 137 | 1380 |
9/16/2019 | B | 446 | 1380 |
9/16/2019 | C | 803 | 1380 |
And my desired output looks like this:
Week | Line_Of_Business | Opportunity_Revenue | Previous_Week_Revenue |
8/12/2019 | A | 123 | |
8/12/2019 | B | 456 | |
8/12/2019 | C | 789 | |
8/19/2019 | A | 120 | 123 |
8/19/2019 | B | 446 | 456 |
8/19/2019 | C | 782 | 789 |
8/26/2019 | A | 131 | 120 |
8/26/2019 | B | 445 | 446 |
8/26/2019 | C | 788 | 782 |
9/2/2019 | A | 125 | 131 |
9/2/2019 | B | 455 | 445 |
9/2/2019 | C | 800 | 788 |
9/9/2019 | A | 134 | 125 |
9/9/2019 | B | 446 | 455 |
9/9/2019 | C | 800 | 800 |
9/16/2019 | A | 137 | 134 |
9/16/2019 | B | 446 | 446 |
9/16/2019 | C | 803 | 800 |
It seems like there should be a way to tell the model to look at the previous week value and filter on the row that matches the Line of Business value, but I'm new to DAX and haven't quite figured out where to put this additional context. How would y'all suggest I update my calculation?
Thank you!
Solved! Go to Solution.
Hi @KCroninKrein
Try to add a calculated column with Dax formula:
PreviousDateRevenue = CALCULATE( SUM('Table'[Opportunity_Revenue]), FILTER( 'Table', 'Table'[Line_Of_Business] = EARLIER('Table'[Line_Of_Business]) && 'Table'[Date] = EARLIER('Table'[Date]) - 7 ) )
If this post helps, then please consider Accepting it as the solution to help the other members find it more quickly
Hi @KCroninKrein
Try to add a calculated column with Dax formula:
PreviousDateRevenue = CALCULATE( SUM('Table'[Opportunity_Revenue]), FILTER( 'Table', 'Table'[Line_Of_Business] = EARLIER('Table'[Line_Of_Business]) && 'Table'[Date] = EARLIER('Table'[Date]) - 7 ) )
If this post helps, then please consider Accepting it as the solution to help the other members find it more quickly
Check out the October 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
115 | |
112 | |
105 | |
95 | |
58 |
User | Count |
---|---|
174 | |
147 | |
136 | |
102 | |
82 |