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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now

Reply
Iamnvt
Continued Contributor
Continued Contributor

Find Previous Value for a measure with multiple conditions

hi,

 

I have a model with 2 facts table: Plan and Actual

Four dimension tables: Date, Hour, Product, Line

 

Model.PNG

 

I need to write a measure (not column) to show the previous value of HC, where for the same line, same product, any date, any hour, if the Plan is blank(), or Plan is 0, and Actual >0, then Previous HC = the most recent HC, where Plan >0

Like this:

 

Model2.PNG

 

here is the PBI file: link

I wrote a measure: 

VAR
__Filtertable  = FILTER(ADDCOLUMNS(CROSSJOIN('Date', Line, 'Product', 'Hour'), "Act", [Sum of Actual], "Pl", [Sum of Plan], "HC", [Sum of HC]),
[Act] + [Pl] <> BLANK())
VAR
__Table1 = ADDCOLUMNS(__Filtertable,
"Previous HC",
  VAR
        __currentdate = FIRSTNONBLANK('Date'[Date],1)
  VAR
        __currentline = FIRSTNONBLANK(Line[Line], 1)
  VAR
        __currentproduct = FIRSTNONBLANK('Product'[Product],1)
  VAR
        __previousdate = CALCULATE(LASTNONBLANK('Date'[Date],1), FILTER(__Filtertable, 'Date'[Date] < __currentdate && Line[Line] = __currentline && 'Product'[Product] = __currentproduct))
   RETURN
        CALCULATE([Sum of HC], FILTER(__Filtertable, Line[Line] = __currentline && 'Product'[Product] = __currentproduct && 'Date'[Date] = __previousdate)
))
RETURN
SUMX(FILTER(__Table1, [Act] > 0 && [Pl] = 0), [Previous HC])

but it doesn't give the result.

please help on this.

Thanks very much

@OwenAuger  : please take a look

 

 

1 ACCEPTED SOLUTION
AlB
Community Champion
Community Champion

Try this, although I believe it's overly complex due to the structure you are using (swap the ";" for "," if necessary)

Sum of Previous HC =
IF (
    [Sum of Actual] > 0 && ( ISBLANK ( [Sum of Plan] ) || [Sum of Plan] = 0);
    VAR AuxTable_ =
        ADDCOLUMNS (
            CROSSJOIN (
                DISTINCT ( Line[Line] );
                CALCULATETABLE (
                    DISTINCT ( 'Date'[Date] );
                    FILTER ( ALL ( 'Date'[Date] ); 'Date'[Date] < SELECTEDVALUE ( 'Date'[Date] ) )
                );
                DISTINCT ( 'Product'[Product] );
                ALL ( 'Hour'[Hour] )
            );
            "AuxPlan_"; [Sum of Plan];
            "AuxHC_"; [Sum of HC];
            "SumActual_"; [Sum of Actual]
        )
    RETURN
        SUMX ( AuxTable_; [AuxHC_] )
)

 

View solution in original post

4 REPLIES 4
AlB
Community Champion
Community Champion

Hi @Iamnvt 

why is the second value hand-written in blue 5 and not 10? You're not considering the current date as valid for the "most recent value"? 

Iamnvt
Continued Contributor
Continued Contributor

Because I am looking the most recent value of line A, Product Apple, where it has Plan > 0 of previous date —> which is the HC value in row#1
AlB
Community Champion
Community Champion

Try this, although I believe it's overly complex due to the structure you are using (swap the ";" for "," if necessary)

Sum of Previous HC =
IF (
    [Sum of Actual] > 0 && ( ISBLANK ( [Sum of Plan] ) || [Sum of Plan] = 0);
    VAR AuxTable_ =
        ADDCOLUMNS (
            CROSSJOIN (
                DISTINCT ( Line[Line] );
                CALCULATETABLE (
                    DISTINCT ( 'Date'[Date] );
                    FILTER ( ALL ( 'Date'[Date] ); 'Date'[Date] < SELECTEDVALUE ( 'Date'[Date] ) )
                );
                DISTINCT ( 'Product'[Product] );
                ALL ( 'Hour'[Hour] )
            );
            "AuxPlan_"; [Sum of Plan];
            "AuxHC_"; [Sum of HC];
            "SumActual_"; [Sum of Actual]
        )
    RETURN
        SUMX ( AuxTable_; [AuxHC_] )
)

 

Iamnvt
Continued Contributor
Continued Contributor

@AlB  this looks ok, but how can I make the Grand Total correct as sum of the row?

Helpful resources

Announcements
November Power BI Update Carousel

Power BI Monthly Update - November 2025

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

Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors