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

Get inspired! Check out the entries from the Power BI DataViz World Championships preliminary rounds and give kudos to your favorites. View the vizzies.

Reply
AnushreeJoshi
Frequent Visitor

compare data sets based on dates

Hello All,

I am new to power bi and I have to build few metrics based on below sample data set.

I have two give two date filters baseline and comparison and have to display a flag or highlight of the value for the column like status or Priority is changed between those dates.

 

Suppose I select 30 Oct in base line slicer and 23 Oct in Comparison slicer

a) I have to create vizulization to highlight/flag the columns that have changed.

b) Count of newly added records also details

c) count of deleted records and details

d) count of changed records ( one of the column value is changed) and details

 

Please help and suggest better implementation for above scenarios.

runidIdStatusPriority
30102023ENG-666MonitoringP1
30102023ENG-111MonitoringP1
30102023ENG-122MonitoringP3
30102023ENG-333MonitoringP3
30102023ENG-555TeminatedP4
25102023ENG-555TeminatedP4
25102023ENG-111MonitoringP1
25102023ENG-122MonitoringP2
25102023ENG-333MonitoringP3
25102023ENG-666MonitoringP4
20102023ENG-111MonitoringP1
20102023ENG-122MonitoringP2
20102023ENG-333MonitoringP3
20102023ENG-555TeminatedP4
20102023ENG-666MonitoringP4
15102023ENG-111MonitoringP1
15102023ENG-122MonitoringP2
15102023ENG-333MonitoringP3
15102023ENG-444MonitoringP4
15102023ENG-555MonitoringP4
1 ACCEPTED SOLUTION
v-yangliu-msft
Community Support
Community Support

Hi  @AnushreeJoshi ,

 

Here are the steps you can follow:

1. Create calculated table.

Date =
DISTINCT('Table'[runid])

vyangliumsft_0-1698824776265.png

2. Create measure.

Measure_A =
var _mindate=MINX(ALLSELECTED('Date'),'Date'[runid])
var _maxdate=MAXX(ALLSELECTED('Date'),'Date'[runid])
var _maxID=SELECTCOLUMNS(FILTER(ALL('Table'),'Table'[runid]=_maxdate),"ID",'Table'[Id])
return
IF(
    MAX('Table'[runid]) = _mindate&&MAX('Table'[Id])in _maxID&&
    MAX('Table'[Status])<>
    MAXX(FILTER(ALL('Table'),'Table'[runid]=_maxdate&&'Table'[Id]=MAX('Table'[Id])),[Status])
    ,1,0)
Measure_B =
var _mindate=MINX(ALLSELECTED('Date'),'Date'[runid])
var _maxdate=MAXX(ALLSELECTED('Date'),'Date'[runid])
var _minID=SELECTCOLUMNS(FILTER(ALL('Table'),'Table'[runid]=_mindate),"ID",'Table'[Id])
return
IF(
    MAX('Table'[runid]) = _maxdate&&NOT(MAX('Table'[Id]))in _minID,1,0)
Measure_C =
var _mindate=MINX(ALLSELECTED('Date'),'Date'[runid])
var _maxdate=MAXX(ALLSELECTED('Date'),'Date'[runid])
var _maxID=SELECTCOLUMNS(FILTER(ALL('Table'),'Table'[runid]=_maxdate),"ID",'Table'[Id])
return
IF(
    MAX('Table'[runid]) = _mindate&&NOT(MAX('Table'[Id]))in _maxID,1,0)

 3. Place [Measure_A], [Measure_B], [Measure_C] into Visual's Filter and set it to 1.

vyangliumsft_1-1698824833644.png

4. Result:

A and D results in a Visual.

vyangliumsft_2-1698824833647.png

 

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

View solution in original post

2 REPLIES 2
v-yangliu-msft
Community Support
Community Support

Hi  @AnushreeJoshi ,

 

Here are the steps you can follow:

1. Create calculated table.

Date =
DISTINCT('Table'[runid])

vyangliumsft_0-1698824776265.png

2. Create measure.

Measure_A =
var _mindate=MINX(ALLSELECTED('Date'),'Date'[runid])
var _maxdate=MAXX(ALLSELECTED('Date'),'Date'[runid])
var _maxID=SELECTCOLUMNS(FILTER(ALL('Table'),'Table'[runid]=_maxdate),"ID",'Table'[Id])
return
IF(
    MAX('Table'[runid]) = _mindate&&MAX('Table'[Id])in _maxID&&
    MAX('Table'[Status])<>
    MAXX(FILTER(ALL('Table'),'Table'[runid]=_maxdate&&'Table'[Id]=MAX('Table'[Id])),[Status])
    ,1,0)
Measure_B =
var _mindate=MINX(ALLSELECTED('Date'),'Date'[runid])
var _maxdate=MAXX(ALLSELECTED('Date'),'Date'[runid])
var _minID=SELECTCOLUMNS(FILTER(ALL('Table'),'Table'[runid]=_mindate),"ID",'Table'[Id])
return
IF(
    MAX('Table'[runid]) = _maxdate&&NOT(MAX('Table'[Id]))in _minID,1,0)
Measure_C =
var _mindate=MINX(ALLSELECTED('Date'),'Date'[runid])
var _maxdate=MAXX(ALLSELECTED('Date'),'Date'[runid])
var _maxID=SELECTCOLUMNS(FILTER(ALL('Table'),'Table'[runid]=_maxdate),"ID",'Table'[Id])
return
IF(
    MAX('Table'[runid]) = _mindate&&NOT(MAX('Table'[Id]))in _maxID,1,0)

 3. Place [Measure_A], [Measure_B], [Measure_C] into Visual's Filter and set it to 1.

vyangliumsft_1-1698824833644.png

4. Result:

A and D results in a Visual.

vyangliumsft_2-1698824833647.png

 

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

@v-yangliu-msft 

Thank you so much for your solution. I will try to implement it and will let you know.

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code FABINSIDER for a $400 discount!

FebPBI_Carousel

Power BI Monthly Update - February 2025

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

March2025 Carousel

Fabric Community Update - March 2025

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

Top Solution Authors