Last Transaction Date and Price

Hi Experts,

How do I ignore date slicer which have dates in future to show last transaction date of an item in the table?

Here is my problem:

I want to find out the last transaction date and the price of an item.

Problem is, I have a slicer and a date column which has dates in future so I am getting blanks for item’s sold date and it’s price in the table.

image

I want to see something like this along with Week Start column in the table: Included in the example tab of attached pbix.

I have included the pbix and looking for what is shown in “Example” tab. How do I achieve that in “Net Sales Forecast” tab?

https://drive.google.com/file/d/1FpwrV-F2s_hRIvIMkrtQC35ncitgpV7R/view?usp=sharing

TIA,
-RK

1 Like

Hi @rit372002 , we aim to consistently improve the topics being posted on the forum to help you in getting a strong solution faster. While waiting for a response, here are some tips so you can get the most out of the forum and other Enterprise DNA resources.

  • Use the forum search to discover if your query has been asked before by another member.
  • When posting a topic with formula make sure that it is correctly formatted to preformatted text </>.
    image
  • Use the proper category that best describes your topic
  • Provide as much context to a question as possible.
  • Include the masked demo pbix file, images of the entire scenario you are dealing with, screenshot of the data model, details of how you want to visualize a result, and any other supporting links and details.

I also suggest that you check the forum guideline How To Use The Enterprise DNA Support Forum. Not adhering to it may sometimes cause delay in getting an answer.

Please also check the How To Mask Sensitive Data thread for some tips on how to mask your pbix file.

Thanks. I hope I followed all the guidelines.

Hi @rit372002,

You had a bidirectional filter in your model, that I replaced with single direction.

I’ve also marked your Date table as a Date table and updated the code for the Week start column

For the date calculation you relied on the id1 = MAX( ‘Sales Order’[Customer-Item] ) but that field wasn’t available in your matrix visual… to hide all blanks I created the VAR BlankVal.

Max - date v2 = 
VAR id1 = CONCATENATE( SELECTEDVALUE(Customer[Parent Retailer AB Number] ), SELECTEDVALUE( 'Item'[Item Number ID] ))
VAR BlankVal = SUMX( { [Net Qty 3YrsAgo] + [Net Qty 2YrsAgo] + [Net Qty LY] + [Net Quantity] }, [Value] )
VAR date1 =
    CALCULATE(
        MAX( 'Sales Order'[Day Date] ),
        REMOVEFILTERS( 'Date' ),
        'Sales Order'[Customer-Item] = id1
    )

RETURN
   IF( BlankVal <> BLANK(), date1 )

Next for the SUM of price on that date.

Max - date price v2 = 
VAR id1 = CONCATENATE( SELECTEDVALUE(Customer[Parent Retailer AB Number] ), SELECTEDVALUE( 'Item'[Item Number ID] ))
VAR BlankVal = SUMX( { [Net Qty 3YrsAgo] + [Net Qty 2YrsAgo] + [Net Qty LY] + [Net Quantity] }, [Value] )
VAR date1 =
    CALCULATE(
        MAX( 'Sales Order'[Day Date] ),
        REMOVEFILTERS( 'Date' ),
        'Sales Order'[Customer-Item] = id1
    )
VAR maxPrice =
    CALCULATE(
        SUM( 'Sales Order'[Net Price Amount] ),
        REMOVEFILTERS( 'Date' ),
        'Sales Order'[Customer-Item] = id1,
        'Sales Order'[Day Date] = date1
    )
RETURN
   IF( BlankVal <> BLANK(), maxPrice )

With this result

I hope this is helpful.

NOTE.
Your model is very, very, very extensive. From a best practice / performance perspective you should never bring more than you actually need (=use). Seeing you have a fact table with 100+ columns makes me wonder if you aren’t in fact building a “one model fits all” instead…

Just something to think about.

2 Likes

Hi @rit372002, we’ve noticed that no response has been received from you since the 7th of January. We just want to check if you still need further help with this post? In case there won’t be any activity on it in the next few days, we’ll be tagging this post as Solved. If you have a follow question or concern related to this topic, please remove the Solution tag first by clicking the three dots beside Reply and then untick the checkbox. Thanks!

@Melissa Thanks you so much! “Remove Filter” solves it, didn’t realize it could be that powerful!

Although I didn’t quite understand why you had to change from bi-direction to single direction and did you make the table as date table for “Best Practices” purposes or was there a technical reason for the solution? Thanks for the tip on keeping Fact table small column wise as well!!!

Thanks,
RK

Hi @rit372002,

Unless you really understand the impact of a bi-directional relationship AND there is no alternative then be my guest and use it. In all other cases don’t. Two main reasons are ambiguity and performance.

Mark as Date table is a best practice.
This will validate your Date table but more importantly prevent the creation of those hidden auto date/time tables that cause bloat of the model - otherwise for each date field in your model a separate hidden date table is created for you. If you have 14 date fields you get a free bonus of 14 hidden date tables. So when you see that suffix .[Date] appear for example you know you have hidden date tables in your model…
Another important reason to mark as a date table is if you want to use DAX time intelligence functions.

Read up on it here.

I hope this is helpful.

Thanks @Melissa, very very helpful and thanks a lot for wonderful solution!

1 Like

Hi @rit372002, did the response provided by @Melissa help you solve your query? If not, how far did you get and what kind of help you need further? If yes, kindly mark the thread as solved. Thanks!

Yes. Thanks so much! @Melissa

Marked it as solution.