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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

DAX - granular reallocation - revenue inbetween a period to days

I have a table Campaign_Report:

 

UID_CAMPAIGNStartFinishGross TotalDurationDaysGrossTotalDay
811402-12-2013 0:0008-12-2013 0:00$33,4217$4,774.43
1621702-12-2013 0:0006-12-2013 0:00$84,1225$16,824.40
2839210-12-2013 0:0015-12-2013 0:00$123,1236$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:

 

DateUID_CAMPAIGNGrossTotalDay
02-12-2013 0:008114$5,570.17
03-12-2013 0:008114$5,570.17
04-12-2013 0:008114$5,570.17
05-12-2013 0:008114$5,570.17
06-12-2013 0:008114$5,570.17
07-12-2013 0:008114$5,570.17
08-12-2013 0:008114$5,570.17
02-12-2013 0:0016217$21,030.50
03-12-2013 0:0016217$21,030.50
04-12-2013 0:0016217$21,030.50
05-12-2013 0:0016217$21,030.50
06-12-2013 0:0016217$21,030.50
10-12-2013 0:0028392$20,520.50
11-12-2013 0:0028392$20,520.50
12-12-2013 0:0028392$20,520.50
13-12-2013 0:0028392$20,520.50
14-12-2013 0:0028392$20,520.50
15-12-2013 0:0028392$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? 

 

 

 

 

 

 

 

 

 

 

1 ACCEPTED SOLUTION
v-yulgu-msft
Employee
Employee

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

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

2 REPLIES 2
v-yulgu-msft
Employee
Employee

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

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Anonymous
Not applicable

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? 

 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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