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
EVBI
Regular Visitor

Sum value between start date and end date

Hi All,

 

I'm very new to PowerBI and need some help on how to sum up revenue in between 2 dates.

 

My data source looks like this:

Date format is (DD/MM/YYYY)

PowerBI1.PNG

 

I would like to calcualte the net rev by month during the active period (between start date and end date). In addition, if the start date is not the first date of the month, it would be calculated on the prorata basis.

For example in January 2018, the net revenue is 17days/31days*1000USD = 548.38USD

In May 2018, net revenue is 1000+500+750+800 = 3050USD

 

Any help would be much appreciated!

1 ACCEPTED SOLUTION
v-yulgu-msft
Employee
Employee

Hi @EVBI,

 

Please refer to below steps:

 

1. I am not sure which column is the unique column in source table, so I first added an Index column in Query Editor mode. 

 

2. Create a calendar table.

Dim date Tb = CALENDAR(DATE(2018,1,1),DATE(2018,12,31))
Days per month = CALCULATE ( DAY ( MAX ( 'Dim date Tb'[Date] ) ), ALLEXCEPT ( 'Dim date Tb', 'Dim date Tb'[Date].[Year], 'Dim date Tb'[Date].[Month] ) )

1.PNG

 

3. Cross Join calendar table and fact data table, and add below calculated columns.

Cross Join Tb =
ADDCOLUMNS (
    FILTER (
        CROSSJOIN ( 'Dim date Tb', data ),
        'Dim date Tb'[Date] >= [start date]
            && 'Dim date Tb'[Date] <= [end date]
    ),
    "Year", YEAR ( [Date] ),
    "Month", MONTH ( [Date] )
)

Count days =
CALCULATE (
    COUNT ( [Date] ),
    ALLEXCEPT (
        'Cross Join Tb',
        'Cross Join Tb'[Year],
        'Cross Join Tb'[Month],
        'Cross Join Tb'[Index]
    )
)

Actual Rev =
'Cross Join Tb'[Count days] / 'Cross Join Tb'[Days per month]
    * 'Cross Join Tb'[Net Rev(USD)]

2.PNG

 

4. Summarize above table.

Summarize Tb =
SUMMARIZE (
    'Cross Join Tb',
    'Cross Join Tb'[Year],
    'Cross Join Tb'[Month],
    'Cross Join Tb'[Index],
    "Net Rev", AVERAGE ( 'Cross Join Tb'[Actual Rev] )
)

3.PNG

 

5. Below calculated table is the final output.

Summarize Tb2 =
SUMMARIZE (
    'Summarize Tb',
    'Summarize Tb'[Year],
    'Summarize Tb'[Month],
    "Sum Rev per month", SUM ( 'Summarize Tb'[Net Rev] )
)

4.PNG

 

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 @EVBI,

 

Please refer to below steps:

 

1. I am not sure which column is the unique column in source table, so I first added an Index column in Query Editor mode. 

 

2. Create a calendar table.

Dim date Tb = CALENDAR(DATE(2018,1,1),DATE(2018,12,31))
Days per month = CALCULATE ( DAY ( MAX ( 'Dim date Tb'[Date] ) ), ALLEXCEPT ( 'Dim date Tb', 'Dim date Tb'[Date].[Year], 'Dim date Tb'[Date].[Month] ) )

1.PNG

 

3. Cross Join calendar table and fact data table, and add below calculated columns.

Cross Join Tb =
ADDCOLUMNS (
    FILTER (
        CROSSJOIN ( 'Dim date Tb', data ),
        'Dim date Tb'[Date] >= [start date]
            && 'Dim date Tb'[Date] <= [end date]
    ),
    "Year", YEAR ( [Date] ),
    "Month", MONTH ( [Date] )
)

Count days =
CALCULATE (
    COUNT ( [Date] ),
    ALLEXCEPT (
        'Cross Join Tb',
        'Cross Join Tb'[Year],
        'Cross Join Tb'[Month],
        'Cross Join Tb'[Index]
    )
)

Actual Rev =
'Cross Join Tb'[Count days] / 'Cross Join Tb'[Days per month]
    * 'Cross Join Tb'[Net Rev(USD)]

2.PNG

 

4. Summarize above table.

Summarize Tb =
SUMMARIZE (
    'Cross Join Tb',
    'Cross Join Tb'[Year],
    'Cross Join Tb'[Month],
    'Cross Join Tb'[Index],
    "Net Rev", AVERAGE ( 'Cross Join Tb'[Actual Rev] )
)

3.PNG

 

5. Below calculated table is the final output.

Summarize Tb2 =
SUMMARIZE (
    'Summarize Tb',
    'Summarize Tb'[Year],
    'Summarize Tb'[Month],
    "Sum Rev per month", SUM ( 'Summarize Tb'[Net Rev] )
)

4.PNG

 

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.

Thank you so much @v-yulgu-msft!

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.