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
Jānis
Frequent Visitor

Calculated table dynamically change from new data

Hello,

 

I have data (in table):

1.PNG

 

I need to calculate and show, what is average employees age at the end of each month in period (for example in period 2017-09 - 2017-12). In example at the end of december (47+27+19)/3. I will show it with Line chart and need to calculate age for every employee at the end of each month in active period.

 

How could I calculate those data? I assume that I need to calculate table...

Or maybe there is other solution.

 

I will appreciate any help.

1 ACCEPTED SOLUTION
v-caliao-msft
Employee
Employee

@Jānis,

 

Create a date table to return the last day of each month.

Create a date table

Date = CALENDAR(DATE(2015,1,1),DATE(2017,12,31))

 

Create a column to get the last day of each month
LastDay = ENDOFMONTH('Date'[Date])

 

Create another table
LastDayofMonth = SUMMARIZE('Date','Date'[LastDay])

 

Create a column to get average age.
AverageAge =
DATEDIFF (
    CALCULATE (
        AVERAGE ( Table2[BirthDate] ),
        FILTER (
            Table2,
            OR (
                ISBLANK ( Table2[InactiveDate] ),
                Table2[InactiveDate] > 'LastDayofMonth'[LastDay]
            )
        )
    ),
    'LastDayofMonth'[LastDay],
    YEAR
)

Capture.JPG

 

Regards,

Charlie Liao

 

View solution in original post

3 REPLIES 3
v-caliao-msft
Employee
Employee

@Jānis,

 

Create a date table to return the last day of each month.

Create a date table

Date = CALENDAR(DATE(2015,1,1),DATE(2017,12,31))

 

Create a column to get the last day of each month
LastDay = ENDOFMONTH('Date'[Date])

 

Create another table
LastDayofMonth = SUMMARIZE('Date','Date'[LastDay])

 

Create a column to get average age.
AverageAge =
DATEDIFF (
    CALCULATE (
        AVERAGE ( Table2[BirthDate] ),
        FILTER (
            Table2,
            OR (
                ISBLANK ( Table2[InactiveDate] ),
                Table2[InactiveDate] > 'LastDayofMonth'[LastDay]
            )
        )
    ),
    'LastDayofMonth'[LastDay],
    YEAR
)

Capture.JPG

 

Regards,

Charlie Liao

 

I needed to make some changes, but in generally it is what I needed.

 

Thank you, @v-caliao-msft

Thank you, @v-caliao-msft!

 

Almost working. I'm still cheking solution (new with DAX).

I found, that I need one more filter - I need to include only active employees, so I need to filter from "Employment Start Date" too, but not sure - is it correct.

 

AverageAge =
DATEDIFF (
    CALCULATE (
        AVERAGE ( Table2[BirthDate] ),

        FILTER (

            Table2, Table2[Employment Start Date] < 'LastDayofMonth'[LastDay]

            ),
        FILTER (
            Table2,
            OR (
                ISBLANK ( Table2[InactiveDate] ),
                Table2[InactiveDate] > 'LastDayofMonth'[LastDay]
            )
        )
    ),
    'LastDayofMonth'[LastDay],
    YEAR
)

 

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.

Top Solution Authors