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
MT
New Member

Estimating monthly values from table using start date/end date

Hello everyone,

 

I have data that looks like this:

 

IdentifierStart DateEnd DateUsage Value
ABCF12341/01/201528/02/2015387
AFDV13451/01/201512/01/2015234
AFDV134513/01/201531/01/2015423

 

What I need to do is to have monthly values for each identifier, but the non-uniform start and end dates are giving me a bit of a headache. Ideal output would look like this:

 

IdentifierMonthUsage Value
ABCF1234Jan-15200
ABCF1234Feb-15187
AFDV1345Jan-15657

 

I realise this would be an estimation, but I just cant figure out a way to do this. I was thinking something along the lines of getting an avg daily value, but I have no idea how I would group those values into months.

 

Has anybody dealt with this kind of data before? Any help would be much appreciated.

 

Cheers

1 ACCEPTED SOLUTION
Phil_Seamark
Employee
Employee

Hi @MT

 

I think this might be getting close

 

Table = 
GROUPBY(
    FILTER(
        CROSSJOIN(
            -- Create and on the fly calendar table with a month column
            ADDCOLUMNS(
                CALENDARAUTO(),
                "Month",FORMAT([Date],"MMM-YY")
                ),
           -- Add a column to our base table that adds an average daily value
            ADDCOLUMNS(
                'Table1',
                        "Averate Usage Per Day",
                        DIVIDE(
                                'Table1'[Usage Value],
                                DATEDIFF(
                                    'Table1'[Start Date],
                                    'Table1'[End Date],DAY
                                        )
                                )
                            )
                            ),
        'Table1'[Start Date] <= [Date] && 
        'Table1'[End Date] >= [Date]
        ),
        -- Perform the actual grouping here --
        -- So Group by --
        [Identifier],
        [Month],
        -- Now sum up the Average daily usage for the above groupings --
        "Usage Value", SUMX(
                            CURRENTGROUP(),
                            [Averate Usage Per Day]
                            )
        )

If I run this over your sample data I get the following result

 

currentgroup.png


To learn more about DAX visit : aka.ms/practicalDAX

Proud to be a Datanaut!

View solution in original post

2 REPLIES 2
v-ljerr-msft
Employee
Employee

Hi @MT,

 

Have you tried the solution provided by @Phil_Seamark above? Does it work in your scenario? If it works, could you accept it as solution to close this thread?

 

If you still have any question on this issue, feel free to post here. Smiley Happy

 

Regards

Phil_Seamark
Employee
Employee

Hi @MT

 

I think this might be getting close

 

Table = 
GROUPBY(
    FILTER(
        CROSSJOIN(
            -- Create and on the fly calendar table with a month column
            ADDCOLUMNS(
                CALENDARAUTO(),
                "Month",FORMAT([Date],"MMM-YY")
                ),
           -- Add a column to our base table that adds an average daily value
            ADDCOLUMNS(
                'Table1',
                        "Averate Usage Per Day",
                        DIVIDE(
                                'Table1'[Usage Value],
                                DATEDIFF(
                                    'Table1'[Start Date],
                                    'Table1'[End Date],DAY
                                        )
                                )
                            )
                            ),
        'Table1'[Start Date] <= [Date] && 
        'Table1'[End Date] >= [Date]
        ),
        -- Perform the actual grouping here --
        -- So Group by --
        [Identifier],
        [Month],
        -- Now sum up the Average daily usage for the above groupings --
        "Usage Value", SUMX(
                            CURRENTGROUP(),
                            [Averate Usage Per Day]
                            )
        )

If I run this over your sample data I get the following result

 

currentgroup.png


To learn more about DAX visit : aka.ms/practicalDAX

Proud to be a Datanaut!

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.