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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
ErMley
Frequent Visitor

Calculated Table for Non-Current and Current Records

Hello, 

 

I am trying to provide some insights on employee movements within a company HR dataset. I have the following fields: 

1. GLOBAL_ID - Employee ID as a whole number 

2. JOB_TITLE - Position of employee as text 

3. CURRENT_RECORD - A binary text column with either 'N' or 'Y' to indicate whether a row is an employee's current record. An employee can have multiple rows based on employment history with different job titles, and the row with "Y" is the employee's up to date employment details. All "old" rows will have a "N" in this column. 

4. VALIDITY_START_DATE - a date column based on when that employee's record was updated with a new record. This is in a relationship with a date dimension table - DIM_DATE[Date]

 

I would like to visualise job title changes in the company in a chord diagram. To do this, I need a "From" field and a "To" field and it needs to be filterable by the aforementioned DIM_DATE[Date] slicer. 

 

I am thinking of approaching this problem by creating a Previous Position table with the employees' most recent job title and "N" in Current Record field, and a Current Position table with employees' job title and "Y" in Current Record field and using CROSSJOIN to join the tables by the GLOBAL_ID column but am running into many errors. Can someone assist me in building out some DAX to do this? 

1 ACCEPTED SOLUTION

The DAX code you provided was useful to break down into steps but no data was being pulled into my table once I executed it (even checking all column names, etc.).

 

I came up with the following to resolve the issue: 

JobChangesTable =
VAR CurrentRecords =
    SELECTCOLUMNS(
        FILTER(
            'Test Data',
            'Test Data'[Current Record ] = "Y"
        ),
        "GLOBAL_ID", 'Test Data'[GLOBAL_ID],
        "To Position", 'Test Data'[JOB_TITLE]
    )

VAR PreviousRecords =
    SELECTCOLUMNS(
        FILTER(
            'Test Data',
            'Test Data'[Current Record ] = "N"
        ),
        "GLOBAL_ID", 'Test Data'[GLOBAL_ID],
        "Validity Start Date", 'Test Data'[Validity Start Date],
        "From Position", 'Test Data'[JOB_TITLE]
    )

VAR RecentPreviousRecords =
    ADDCOLUMNS(
        GROUPBY(
            PreviousRecords,
            [GLOBAL_ID],
            "MaxDate", MAXX(CURRENTGROUP(), [Validity Start Date])
        ),
        "From Position",
        VAR GlobalID = [GLOBAL_ID]
        VAR MaxDate = [MaxDate]
        RETURN
            MAXX(
                FILTER(
                    PreviousRecords,
                    [GLOBAL_ID] = GlobalID &&
                    [Validity Start Date] = MaxDate
                ),
                [From Position]
            )
    )

VAR CrossJoinedTable =
    SELECTCOLUMNS(
        CROSSJOIN(
            SELECTCOLUMNS(CurrentRecords, "GLOBAL_ID_Curr", [GLOBAL_ID], "To Position", [To Position]),
            SELECTCOLUMNS(RecentPreviousRecords, "GLOBAL_ID_Prev", [GLOBAL_ID], "From Position", [From Position])
        ),
        "GLOBAL_ID_Curr", [GLOBAL_ID_Curr],
        "To Position", [To Position],
        "GLOBAL_ID_Prev", [GLOBAL_ID_Prev],
        "From Position", [From Position]
    )

RETURN
    FILTER(
        CrossJoinedTable,
        [GLOBAL_ID_Curr] = [GLOBAL_ID_Prev]
    )


View solution in original post

2 REPLIES 2
Anonymous
Not applicable

Hi  @ErMley ,

I created some data:

vyangliumsft_0-1719989890710.png

 

Here are the steps you can follow:

1. Create calculated table.

 

TrueTbale =
VAR _table =
    FILTER ( 'Table', [CURRENT_RECORD] = "Y" )
VAR _table2 =
    ADDCOLUMNS (
        _table,
        "ToTest",
            MINX (
                FILTER (
                    _table,
                    [GLOBAL_ID ] = EARLIER ( [GLOBAL_ID ] )
                        && [VALIDITY_START_DATE] > EARLIER ( [VALIDITY_START_DATE] )
                ),
                [VALIDITY_START_DATE]
            )
    )
VAR _table3 =
    ADDCOLUMNS (
        _table2,
        "To",
            MINX (
                FILTER (
                    _table2,
                    [GLOBAL_ID ] = EARLIER ( [GLOBAL_ID ] )
                        && [VALIDITY_START_DATE] = EARLIER ( [ToTest] )
                ),
                [JOB_TITLE]
            )
    )
VAR _table4 =
    SELECTCOLUMNS (
        FILTER ( _table3, [To] <> BLANK () ),
        "GLOBAL_ID", [GLOBAL_ID ],
        "From", [JOB_TITLE],
        "To", [To]
    )
RETURN
    _table4

 

2. Result:

vyangliumsft_1-1719989890711.png

 

If the above results do not meet your expectations, can you express the expected results in the form of a picture, we can help you better.

 

Best Regards,

Liu Yang

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly

The DAX code you provided was useful to break down into steps but no data was being pulled into my table once I executed it (even checking all column names, etc.).

 

I came up with the following to resolve the issue: 

JobChangesTable =
VAR CurrentRecords =
    SELECTCOLUMNS(
        FILTER(
            'Test Data',
            'Test Data'[Current Record ] = "Y"
        ),
        "GLOBAL_ID", 'Test Data'[GLOBAL_ID],
        "To Position", 'Test Data'[JOB_TITLE]
    )

VAR PreviousRecords =
    SELECTCOLUMNS(
        FILTER(
            'Test Data',
            'Test Data'[Current Record ] = "N"
        ),
        "GLOBAL_ID", 'Test Data'[GLOBAL_ID],
        "Validity Start Date", 'Test Data'[Validity Start Date],
        "From Position", 'Test Data'[JOB_TITLE]
    )

VAR RecentPreviousRecords =
    ADDCOLUMNS(
        GROUPBY(
            PreviousRecords,
            [GLOBAL_ID],
            "MaxDate", MAXX(CURRENTGROUP(), [Validity Start Date])
        ),
        "From Position",
        VAR GlobalID = [GLOBAL_ID]
        VAR MaxDate = [MaxDate]
        RETURN
            MAXX(
                FILTER(
                    PreviousRecords,
                    [GLOBAL_ID] = GlobalID &&
                    [Validity Start Date] = MaxDate
                ),
                [From Position]
            )
    )

VAR CrossJoinedTable =
    SELECTCOLUMNS(
        CROSSJOIN(
            SELECTCOLUMNS(CurrentRecords, "GLOBAL_ID_Curr", [GLOBAL_ID], "To Position", [To Position]),
            SELECTCOLUMNS(RecentPreviousRecords, "GLOBAL_ID_Prev", [GLOBAL_ID], "From Position", [From Position])
        ),
        "GLOBAL_ID_Curr", [GLOBAL_ID_Curr],
        "To Position", [To Position],
        "GLOBAL_ID_Prev", [GLOBAL_ID_Prev],
        "From Position", [From Position]
    )

RETURN
    FILTER(
        CrossJoinedTable,
        [GLOBAL_ID_Curr] = [GLOBAL_ID_Prev]
    )


Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

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