Current period vs. previous period WITHOUT date column

Hi @corkemp

You need to create 2 disconnected table from the main table.

Table 1–

  1. Goto “Data” view and select “New Table”

  2. Use below DAX to create new table with table name “SelectedRCy1”(you can change as per your choice)
    SelectedRCy1 = DISTINCT('Masked Report Data'[Report Cycle Name])

  3. Rename the column as “Selection 1”

Table 2–

  1. Goto “Data” view and select “New Table”

  2. Use below DAX to create new table with table name “SelectedRCy2”(you can change as per your choice)
    SelectedRCy2 = DISTINCT('Masked Report Data'[Report Cycle Name])

  3. Rename the column as “Selection 2”

You will have as below.

Make sure it is not connected to main table below data model FYR.

Create new measures as below.

First selected Period = 
CALCULATE ( 
    AVERAGEX ( 
        'Masked Report Data',
        'Masked Report Data'[Average of Attainment Track]
    ),
    FILTER ( 
        'Masked Report Data',
        [Report Cycle Name] = MIN(SelectedRCy1[Selection 1])
    )
)

Second selected Period = 
CALCULATE ( 
    AVERAGEX ( 
        'Masked Report Data',
        'Masked Report Data'[Average of Attainment Track]
    ),
    FILTER ( 
        'Masked Report Data',
        [Report Cycle Name] = MIN(SelectedRCy2[Selection 2])
    )
)

Difference = 
[First selected Period] - [Second selected Period]

Now you can create all the views. I can’t upload the pbix as using office system.

3 Likes