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
Arnault_
Resolver III
Resolver III

LASTNONBLANKVALUE challenging problem

Hi All,

I have created an inventory data model where I calculate the inventory position at the end of each day. The dataset corresponds to a transactions table and not a snapshot table. I have used the LASTNONBLANKVALUE statement to get the expected result.

For each transaction, I have the ending balance value. I just need to get this value and populate it to the next day until there is another transaction.

Sometimes, there are more than one transaction each day, then I use the "sequence_no" to determine the lastest transaction.

To understand the model and the measure below, it is important to consider a unique product is composed of the following colums = warehouse / product_id / version_id 

The problem I have is that the value is not populated over all the dates and you can see in the below screenshot that some dates are missing.

 

2021-03-26_22h31_54.png

 

The problem comes from the complexity of the data model. If you take a look at the measure I have created, I used a virtual table to make sure the LASTNONBLANKVALUE would iterate through the following columns: warehouse, product_id and version_id. The SUMX statement allows to get the correct total (column on the right).

 

 

 

 

 

Last Known Inventory = 
VAR LastKnownDate =
    MAX ( 'Date'[Date] )
VAR lastKnownInventory =
    CALCULATETABLE (
        SUMMARIZE (
            MyData,
            MyData[warehouse],
            MyData[product_id],
            MyData[version_id],
            "LastKnownInventory",
                CALCULATE (
                    LASTNONBLANKVALUE (
                        MyData[sequence_no],
                        SUMX ( MyData, MyData[ending_balance] )
                    ),
                    'Date'[Date] <= LastKnownDate
                )
        )
    )
RETURN 
   SUMX ( lastKnownInventory, [LastKnownInventory] )

 

 

 

 

Here is the PBIX.

Thanks for your help. 

4 REPLIES 4
Jihwan_Kim
Super User
Super User

Hi, @Arnault_ 

Please correct me if I wrongly understood your question.

I tried the below measure, and I think it works.

 

lastupdateinventory =
VAR maxdate =
MAX ( 'Date'[Date] )
VAR lastnonblankinventorybalance =
CALCULATE (
LASTNONBLANKVALUE (
'Date'[Date],
CALCULATE (
SUMX ( MyData, MyData[ending_balance] ),
FILTER (
ALLSELECTED ( MyData ),
MyData[sequence_no] = MAXX ( MyData, MyData[sequence_no] )
)
)
),
FILTER ( ALLSELECTED ( 'Date' ), 'Date'[Date] <= maxdate )
)
RETURN
lastnonblankinventorybalance
 

Jihwan Kim

If this post helps, then please consider accept it as the solution to help the other members find it more quickly.

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 ,

Thank you for your time and proposal.

Your measure meets one of the requirements since the inventory values are displayed for every day even when there is no transaction. Still, there is something which does not work.

In my dataset, we can select the 5th of November to illustrate the problem. On that particular date, there are several transactions and at least one transaction per warehouse. You measure does not take into account the fact there are 2 warehouses and it only selects the latest transaction of this day. Normally, the latest transaction for BDX and the latest transaction for DUB should be selected and aggregated. This works in my measure. That's why in my measure I use a virtual table with product_id, version_id and warehouse. Maybe I should create a unique id combining these columns. What do you think?

Hi, @Arnault_ 

Thank you very much for your feedback, and I could understand much better.

If it is OK with you, please try the below.

 

lastupdateinventory fix =
VAR maxdate =
MAX ( 'Date'[Date] )
VAR lastnonblankinventorybalance =
CALCULATE (
LASTNONBLANKVALUE (
'Date'[Date],
SUMX (
SUMMARIZE (
MyData,
MyData[warehouse],
MyData[product_id],
MyData[version_id],
"@maxseqbalance",
CALCULATE (
SUM ( MyData[ending_balance] ),
FILTER ( MyData, MyData[sequence_no] = MAX ( MyData[sequence_no] ) )
)
),
[@maxseqbalance]
)
),
FILTER ( ALLSELECTED ( 'Date' ), 'Date'[Date] <= maxdate )
)
RETURN
lastnonblankinventorybalance
 

Hi, My name is Jihwan Kim.

If this post helps, then please consider accept it as the solution to help other members find it faster.

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 ,

Thank you again for your time and efforts.

We are getting close to the requirements. I am just thinking that maybe DAX is not the best approach to obtain what I am looking for. Maybe some pre-build in SQL would be better. Anyway, here is the remaining issue: the total on the right is not working properly. The first table corresponds to my measure, the 2nd to yours.

You can see two examples highlithed. On the 12th of May, the total shows 320 650 which corresponds to the 1st item only. In your measure the last non blank value is populated for the 2nd item but it is not taken into account in the sum (in the total on the right).

For the next row, on the 13th of May, it works because there are transactions on that day and as you can see it with my measure (first table), the sumx works perfectly.

From a business perspective, if I want to know the quantity in stock for these 2 items (in total) at the end of the 12th of May, your measure would tell me 320 650, instead of (320 650 + 432 400). Voilà.

image.png

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.