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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
thinker_02
Regular Visitor

Previous Status Measure

The "Profit" table has columns Product ID, Date, and Status, with Status categorized as High, Low, or Medium.

Snapshot of the Profit table:

| Product ID | Date | Status |
|------------|------------|--------|
| ID1 | 4/4/2022 | Low |
| ID2 | 8/1/2022 | High |
| ID1 | 10/12/2022 | High |
| ID1 | 2/1/2022 | Medium |
| ID2 | 1/1/2023 | Low |
| ID2 | 6/7/2022 | Medium |
| ID1 | 7/7/2023 | Medium |

Three measures were created for analysis:

 Min Date: 6/12/2022 and Max Date: 4/2/2023 (I selected them in Date Slicer too)
1.Latest Date: Checks date per Stock ID within the min and max dates.
2.Second Date: Checks date per Stock ID less than the min date, i.e., any entry just before the Latest Date.
3.Status Latest: Shows the Status per ID on the Latest Date.

Looking for help to create a measure for **Status Previous** to display the Status per ID on the Second Date.

Resulting table:

| Stock ID | Latest Date | Second Date | Status Latest | (Expected)Status Previous |
|----------|-------------|-------------|---------------|------------------|
| ID1 | 10/12/2022 | 4/4/2022 | High | Low |
| ID2 | 1/1/2023 | 6/7/2022 | Low | Medium |


Status Previous measure is intended to reveal the status of each ID on the second most recent date in the specified date range.

For the measures:

DAX Measures-

 

 

 

LatestDate = MAX('Profit'[Date])
SecondDate =
VAR MinDate = DATE(2022, 12, 6)
VAR MaxDate = DATE(2023, 2, 4)
VAR LatestDate = MAX('Profit'[Date])
RETURN
IF (
AND(
LatestDate >= MinDate,
LatestDate <= MaxDate
),
CALCULATE(
MAX('Profit'[Status]),
'Profit'[Date] < LatestDate
),
BLANK()
)
Latest Status =
CALCULATE(
MAX('Profit'[Status]),
FILTER(
'Profit',
'Profit'[Date] = [LatestDate]
)
)

 

 

 

However, when creating the Status Previous measure, it returns blank values. Looking forward. Thanks in advance!!

1 ACCEPTED SOLUTION
v-yangliu-msft
Community Support
Community Support

Hi @thinker_02  ,

 

 

Here are the steps you can follow:

1. Create measure.

Flag =
var _date=
MAXX(
   FILTER(ALLSELECTED('Table'),'Table'[Product ID]=MAX('Table'[Product ID])),[Date])
return
IF(
    MAX('Table'[Date])=_date,1,0)
Second Date =
 var _date=
MAXX(
    FILTER(ALLSELECTED('Table'),'Table'[Product ID]=MAX('Table'[Product ID])),[Date])
return
MAXX(
    FILTER(ALL('Table'),
    'Table'[Product ID]=MAX('Table'[Product ID])&&'Table'[Date]<_date),[Date])
Status Latest =
var _date=
MAXX(
    FILTER(ALLSELECTED('Table'),'Table'[Product ID]=MAX('Table'[Product ID])),[Date])
var _maxdate=
MAXX(
    FILTER(ALL('Table'),
    'Table'[Product ID]=MAX('Table'[Product ID])&&'Table'[Date]<_date),[Date])
return
MAXX(
    FILTER(ALL('Table'),
   'Table'[Product ID]=MAX('Table'[Product ID])&& 'Table'[Date] =_maxdate),[Status])

2. Place [Flag]in Filters, set is=1, apply filter.

vyangliumsft_0-1705293661120.png

3. Result:

vyangliumsft_1-1705293661122.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 @thinker_02  ,

 

 

Here are the steps you can follow:

1. Create measure.

Flag =
var _date=
MAXX(
   FILTER(ALLSELECTED('Table'),'Table'[Product ID]=MAX('Table'[Product ID])),[Date])
return
IF(
    MAX('Table'[Date])=_date,1,0)
Second Date =
 var _date=
MAXX(
    FILTER(ALLSELECTED('Table'),'Table'[Product ID]=MAX('Table'[Product ID])),[Date])
return
MAXX(
    FILTER(ALL('Table'),
    'Table'[Product ID]=MAX('Table'[Product ID])&&'Table'[Date]<_date),[Date])
Status Latest =
var _date=
MAXX(
    FILTER(ALLSELECTED('Table'),'Table'[Product ID]=MAX('Table'[Product ID])),[Date])
var _maxdate=
MAXX(
    FILTER(ALL('Table'),
    'Table'[Product ID]=MAX('Table'[Product ID])&&'Table'[Date]<_date),[Date])
return
MAXX(
    FILTER(ALL('Table'),
   'Table'[Product ID]=MAX('Table'[Product ID])&& 'Table'[Date] =_maxdate),[Status])

2. Place [Flag]in Filters, set is=1, apply filter.

vyangliumsft_0-1705293661120.png

3. Result:

vyangliumsft_1-1705293661122.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

Ashish_Mathur
Super User
Super User

Hi,

PBI file attached.

Ashish_Mathur_0-1705198248620.png

 


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

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 MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.