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

Shape the future of the Fabric Community! Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions. Take survey.

Reply
Anonymous
Not applicable

End of Day Stock Count

Hi all - I have been having some issues calculating an "End Of Day Stock Count" in DAX. (Link below)

 

https://drive.google.com/open?id=13-Aam9seytTAn8FJ5cprCa5s0TF77waR 

 

I am looking to get a measure to calculate the number of items in stock (Equipment Number) at the end of the day, this has proven to be tricky as some items arrive and dispatch on the same day. also, the logic is that if the item has no Departure Date it is still in stock.

 

Hope you can help... link to the data is above

 

Thank you!

DAX 

 

1 ACCEPTED SOLUTION
sturlaws
Resident Rockstar
Resident Rockstar

Hi @Anonymous 

 

You can try something like this:

End of day stock count = 
VAR _dateFilterContext =
    IF ( HASONEVALUE ( Calender[Date] ); MIN ( Calender[Date] ); BLANK () )
RETURN
    IF (
        NOT ( ISBLANK ( _dateFilterContext ) );
        CALCULATE(
            DISTINCTCOUNT('Table'[EquipmentNumber]);        
            FILTER (
                'Table';
                (
                    ISBLANK ( 'Table'[DepartureDate] )
                        && 'Table'[ArrivalDate] <= _dateFilterContext
                )
                    || ( 'Table'[DepartureDate] > _dateFilterContext
                    && 'Table'[ArrivalDate] <= _dateFilterContext )
            )
        );
        BLANK ()
    )

 

To get this to work, you need a calendar table. Here is a demo, using your data: report

 

Cheers,
Sturla

If this post helps, then please consider Accepting it as the solution. Kudos are nice too.

View solution in original post

2 REPLIES 2
sturlaws
Resident Rockstar
Resident Rockstar

Hi @Anonymous 

 

You can try something like this:

End of day stock count = 
VAR _dateFilterContext =
    IF ( HASONEVALUE ( Calender[Date] ); MIN ( Calender[Date] ); BLANK () )
RETURN
    IF (
        NOT ( ISBLANK ( _dateFilterContext ) );
        CALCULATE(
            DISTINCTCOUNT('Table'[EquipmentNumber]);        
            FILTER (
                'Table';
                (
                    ISBLANK ( 'Table'[DepartureDate] )
                        && 'Table'[ArrivalDate] <= _dateFilterContext
                )
                    || ( 'Table'[DepartureDate] > _dateFilterContext
                    && 'Table'[ArrivalDate] <= _dateFilterContext )
            )
        );
        BLANK ()
    )

 

To get this to work, you need a calendar table. Here is a demo, using your data: report

 

Cheers,
Sturla

If this post helps, then please consider Accepting it as the solution. Kudos are nice too.

Anonymous
Not applicable

Thank you, this is just what I needed.

 

As my dataset is extremely large I had to create a table with just the keys and run the measure from the data in the new table.

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

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.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.