March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
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)
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!
Solved! Go to Solution.
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] ) )
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)]
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] ) )
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] ) )
Best regards,
Yuliana Gu
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] ) )
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)]
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] ) )
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] ) )
Best regards,
Yuliana Gu
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
124 | |
87 | |
85 | |
70 | |
51 |
User | Count |
---|---|
205 | |
153 | |
97 | |
79 | |
69 |