Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code FABINSIDER for a $400 discount.
Register nowGet inspired! Check out the entries from the Power BI DataViz World Championships preliminary rounds and give kudos to your favorites. View the vizzies.
I have a table Campaign_Report:
UID_CAMPAIGN | Start | Finish | Gross Total | DurationDays | GrossTotalDay |
8114 | 02-12-2013 0:00 | 08-12-2013 0:00 | $33,421 | 7 | $4,774.43 |
16217 | 02-12-2013 0:00 | 06-12-2013 0:00 | $84,122 | 5 | $16,824.40 |
28392 | 10-12-2013 0:00 | 15-12-2013 0:00 | $123,123 | 6 | $20,520.50 |
note that the start and finish dates are inclusive. I'd like to proportion the revenur to each day so that I have a dynamic table that looks like this:
Date | UID_CAMPAIGN | GrossTotalDay |
02-12-2013 0:00 | 8114 | $5,570.17 |
03-12-2013 0:00 | 8114 | $5,570.17 |
04-12-2013 0:00 | 8114 | $5,570.17 |
05-12-2013 0:00 | 8114 | $5,570.17 |
06-12-2013 0:00 | 8114 | $5,570.17 |
07-12-2013 0:00 | 8114 | $5,570.17 |
08-12-2013 0:00 | 8114 | $5,570.17 |
02-12-2013 0:00 | 16217 | $21,030.50 |
03-12-2013 0:00 | 16217 | $21,030.50 |
04-12-2013 0:00 | 16217 | $21,030.50 |
05-12-2013 0:00 | 16217 | $21,030.50 |
06-12-2013 0:00 | 16217 | $21,030.50 |
10-12-2013 0:00 | 28392 | $20,520.50 |
11-12-2013 0:00 | 28392 | $20,520.50 |
12-12-2013 0:00 | 28392 | $20,520.50 |
13-12-2013 0:00 | 28392 | $20,520.50 |
14-12-2013 0:00 | 28392 | $20,520.50 |
15-12-2013 0:00 | 28392 | $20,520.50 |
So, the Date column only lists what is between each Campaign Start and Finish dates, the UID on each line and the individual daily breakdown of each. I've been trying to write a DAX formula to convert this, I have the dates in a table using
Table = CALENDAR( minx(Campaign_Report,Campaign_Report[Start]), maxx(Campaign_Report,Campaign_Report[Finish] ))
But can anyone point me in the right direction as to DAX to split out each day total into the second table?
Solved! Go to Solution.
Hi, @Anonymous
Create a interim table:
Daily Breakdown = GENERATE( SUMMARIZE(Campaign_Report, Campaign_Report[UID_CAMPAIGN], Campaign_Report[GrossTotalDay],Campaign_Report[Start],Campaign_Report[Finish]), DATESBETWEEN(DateDimension[DateSK], min(Campaign_Report[Start]), max(Campaign_Report[Finish]) ) )
In this table, create a calculated column:
Column = IF ( 'Daily Breakdown'[DateSK] >= 'Daily Breakdown'[Start] && 'Daily Breakdown'[DateSK] <= 'Daily Breakdown'[Finish], 'Daily Breakdown'[UID_CAMPAIGN], BLANK () )
Then, create the final table that you expected:
Daily Breakdown2 = SELECTCOLUMNS ( CALCULATETABLE ( 'Daily Breakdown', 'Daily Breakdown'[Column] <> BLANK () ), "UID_CAMPAIGN", 'Daily Breakdown'[UID_CAMPAIGN], "GrossTotal", 'Daily Breakdown'[GrossTotalDay], "Date", 'Daily Breakdown'[DateSK] )
Best regards,
Yuliana Gu
Hi, @Anonymous
Create a interim table:
Daily Breakdown = GENERATE( SUMMARIZE(Campaign_Report, Campaign_Report[UID_CAMPAIGN], Campaign_Report[GrossTotalDay],Campaign_Report[Start],Campaign_Report[Finish]), DATESBETWEEN(DateDimension[DateSK], min(Campaign_Report[Start]), max(Campaign_Report[Finish]) ) )
In this table, create a calculated column:
Column = IF ( 'Daily Breakdown'[DateSK] >= 'Daily Breakdown'[Start] && 'Daily Breakdown'[DateSK] <= 'Daily Breakdown'[Finish], 'Daily Breakdown'[UID_CAMPAIGN], BLANK () )
Then, create the final table that you expected:
Daily Breakdown2 = SELECTCOLUMNS ( CALCULATETABLE ( 'Daily Breakdown', 'Daily Breakdown'[Column] <> BLANK () ), "UID_CAMPAIGN", 'Daily Breakdown'[UID_CAMPAIGN], "GrossTotal", 'Daily Breakdown'[GrossTotalDay], "Date", 'Daily Breakdown'[DateSK] )
Best regards,
Yuliana Gu
I've inched closer with this expression:
Daily Breakdown = GENERATE(
SUMMARIZE(Campaign_Report,
Campaign_Report[UID_CAMPAIGN],
Campaign_Report[GrossTotalDay]),
DATESBETWEEN(DateDimension[DateSK], min(Campaign_Report[Start]), max(Campaign_Report[Finish])
)
)
However DATESBETWEEN doesn't isolate the days specific to each campaign, to does all the dates of ALL campaigns. Can anyone give me a hint (if you can't tell I am new to DAX!) where to put DATESBETWEEN so it only affects the Start to Finish dates of each campaign?
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code FABINSIDER for a $400 discount!
Check out the February 2025 Power BI update to learn about new features.
User | Count |
---|---|
86 | |
71 | |
68 | |
50 | |
31 |
User | Count |
---|---|
118 | |
100 | |
73 | |
65 | |
40 |