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
Rsquare
Frequent Visitor

DAX measure: MIN date for historical data in live connection

Hello all,

 

I have a live connection to a SQL table “table1” with historical data.

 

Example Data:

ID

Status

Start

End

Changed

1

A

2022-05-13

 

2022-05-13

1

B

2022-05-13

 

2022-05-14

2

A

2022-05-15

 

2022-05-15

3

A

2022-05-15

 

2022-05-15

2

C

2022-05-15

2022-05-16

2022-05-16

3

B

2022-05-15

 

2022-05-16

3

B

2022-05-15

 

2022-05-17

3

C

2022-05-15

2022-05-18

2022-05-18

4

A

2022-05-15

 

2022-05-15

4

A

2022-05-15

 

2022-05-16

5

A

2022-05-16

 

2022-05-16

 

What to achieve:

Now, I would like to get the MIN Start-date with Status “A” if the corresponding ID had no other Status since then.

 

Expected Result:

The output regarding the example table would be 2022-05-15. Solution: ID 4 and ID 5 are the only IDs that did not switch their state. ID 4 provides an earlier start date then ID 5.

 

 

I tried different approaches, like comparing a subset of Status A with a subset of other statuses to get the IDs that are in subset A but not in the other one. Another means could be an index if it would be possible to calculate a column.

 

However, since it is a live connection, I cannot calculate new tables or columns. The DAX measure has to be calculated without those intermediate steps. A change of the connection type is not possible.

 

I appreciate your help!

Thanks.

1 ACCEPTED SOLUTION
Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

 

sample.png

 

Desired outcome measure: = 
VAR _IDunderA =
    SUMMARIZE ( FILTER ( Data, Data[Status] = "A" ), Data[ID] )
VAR _IDunderothers =
    SUMMARIZE ( FILTER ( Data, Data[Status] <> "A" ), Data[ID] )
VAR _IDonlyA =
    EXCEPT ( _IDunderA, _IDunderothers )
VAR _newtable =
    CALCULATETABLE ( Data, TREATAS ( _IDonlyA, Data[ID] ) )
RETURN
    MINX ( _newtable, Data[Start] )

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


View solution in original post

2 REPLIES 2
Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

 

sample.png

 

Desired outcome measure: = 
VAR _IDunderA =
    SUMMARIZE ( FILTER ( Data, Data[Status] = "A" ), Data[ID] )
VAR _IDunderothers =
    SUMMARIZE ( FILTER ( Data, Data[Status] <> "A" ), Data[ID] )
VAR _IDonlyA =
    EXCEPT ( _IDunderA, _IDunderothers )
VAR _newtable =
    CALCULATETABLE ( Data, TREATAS ( _IDonlyA, Data[ID] ) )
RETURN
    MINX ( _newtable, Data[Start] )

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


Hi @Jihwan_Kim,

 

thanks for the solution! I got an additional request and need the ID/IDs according to this MIN value. Tried SELECTEDVALUE with FILTER regarding minx. But it does not work.   

 

Any help is appreciated, thanks! 

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