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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Anonymous
Not applicable

Calculate 14 days running maximum competitor price for each individual competitor in DAX

Given that I have competitor name, competitor price & date columns, I have to calculate 14 days running maximum competitor price for each individual competitor in DAX

 

Sample table: (input)

Product IDCompetitor NameCompetitor PriceDate
508861

XYZ.dk

139kr

13/09/21
508861ABC.dk125kr13/09/21
508861ABC.dk129kr14/09/21
508861ABC.dk119kr14/09/21
508861XYZ.dk109kr14/09/21
508861ABC.dk119kr15/09/21
508861ABC.dk119kr16/09/21
508861ABC.dk139kr17/09/21
508861ABC.dk119kr18/09/21
508861ABC.dk119kr19/09/21
508861

XYZ.dk

119kr

21/09/21
508861

XYZ.dk

119kr

21/09/21
508861

XYZ.dk

119kr

21/09/21
508861

XYZ.dk

109kr

22/09/21
508861

XYZ.dk

109kr

24/09/21
508861

ABC.dk

109kr

26/09/21
508861

ABC.dk

129kr

28/09/21
508861

ABC.dk

119kr

29/09/21
508861

XYZ.dk

139kr

30/09/21

 

Expected Output:

Product IDCompetitor NameCompetitor PriceDateMax price
508861

XYZ.dk

139kr

13/09/21 
508861ABC.dk125kr13/09/21 
508861ABC.dk129kr14/09/21 
508861ABC.dk119kr14/09/21 
508861XYZ.dk109kr14/09/21 
508861ABC.dk119kr15/09/21 
508861ABC.dk119kr16/09/21 
508861ABC.dk139kr17/09/21 
508861ABC.dk119kr18/09/21 
508861ABC.dk119kr19/09/21 
508861

XYZ.dk

119kr

21/09/21 
508861

XYZ.dk

119kr

21/09/21 
508861

XYZ.dk

119kr

21/09/21 
508861

XYZ.dk

109kr

24/09/21 
508861

XYZ.dk

109kr

24/09/21 
508861

ABC.dk

109kr

26/09/21 
508861

ABC.dk

129kr

28/09/21 
508861

ABC.dk

119kr

29/09/21  139kr
508861

XYZ.dk

139kr

30/09/21  139kr

 

Current DAX code: (not working as wished to)

 

Max price = 
MAXX(DATESINPERIOD('calendar'[Date], LASTDATE('calendar'[Date]),-14,DAY),competitor_v2[CompetitorPrice])

 

 

 Also tried this:

 

Max price last 14 days = CALCULATE(max(competitor_v2[CompetitorPrice]), TODAY()-14 > competitor_v2[Date])

 

 

Note: There is no explicit relation with any other table than the (Calendar) date table. (Considering that calendar[date] & competitor_v2[date] is same)


Would really appreciate it if anyone can reflect on what is that I could be missing. 🙂

1 ACCEPTED SOLUTION

Hi, @Anonymous 

 

Your question is whether you only want the last date to display the maximum value?

You can add conditions to judge the date in the original formula.

Max price =
IF (
    [Date]
        = CALCULATE (
            MAX ( 'Table'[Date] ),
            FILTER ( 'Table', [Competitor Name] = EARLIER ( 'Table'[Competitor Name] ) )
        ),
    IF (
        'Table'[Date] - MIN ( 'Table'[Date] ) < 14,
        BLANK (),
        MAXX (
            FILTER (
                'Table',
                [Date]
                    >= EARLIER ( 'Table'[Date] ) - 14
                    && [Date] <= EARLIER ( 'Table'[Date] )
            ),
            'Table'[Competitor Price]
        )
    ),
    BLANK ()
)

vzhangti_0-1637747009967.png

 

Best Regards,

Community Support Team _Charlotte

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

6 REPLIES 6
v-zhangti
Community Support
Community Support

Hi, @Anonymous 

 

You can try the following methods.

Max price = 
IF (
    [Date] - MIN ( 'Table'[Date] ) < 14,
    BLANK (),
    MAXX (
        FILTER (
            'Table',
            [Date]
                >= EARLIER ( 'Table'[Date] ) - 14
                && [Date] <= EARLIER ( 'Table'[Date] )
        ),
        'Table'[Competitor Price]
    )
)

vzhangti_0-1637574821201.png

 

Best Regards,

Community Support Team _Charlotte

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

 

Anonymous
Not applicable

Hi @v-zhangti, thanks for trying it out for me, I actually tried with my data, and apparently is not working as expected. 

Please find the image below (Please refer the Maximum Price column)

Prasad_Jagtap_0-1637676852245.png
Any further guidance is appreciated. 🙂

 

Hi, @Anonymous 

 

Your question is whether you only want the last date to display the maximum value?

You can add conditions to judge the date in the original formula.

Max price =
IF (
    [Date]
        = CALCULATE (
            MAX ( 'Table'[Date] ),
            FILTER ( 'Table', [Competitor Name] = EARLIER ( 'Table'[Competitor Name] ) )
        ),
    IF (
        'Table'[Date] - MIN ( 'Table'[Date] ) < 14,
        BLANK (),
        MAXX (
            FILTER (
                'Table',
                [Date]
                    >= EARLIER ( 'Table'[Date] ) - 14
                    && [Date] <= EARLIER ( 'Table'[Date] )
            ),
            'Table'[Competitor Price]
        )
    ),
    BLANK ()
)

vzhangti_0-1637747009967.png

 

Best Regards,

Community Support Team _Charlotte

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

 

Anonymous
Not applicable

Hi @v-zhangti, thank you so much for your inputs and for practically trying it out for me, I'll give it a run for my data set and see if runs smoothly for me and gets me the desired outcome. 😁
 
Best,
Prasad

Anonymous
Not applicable

Hi @VahidDM, thank you so much for the comment, I will quickly try to update my post according to suggestions. Much appreciated..!

VahidDM
Super User
Super User

Hi @Anonymous 

 

Can you post sample data as text and expected output?
Not enough information to go on;

please see this post regarding How to Get Your Question Answered Quickly:
https://community.powerbi.com/t5/Community-Blog/How-to-Get-Your-Question-Answered-Quickly/ba-p/38490

The most important parts are:
1. Sample data as text, use the table tool in the editing bar
2. Expected output from sample data
3. Explanation in words of how to get from 1. to 2.
4. Relation between your tables

Appreciate your Kudos!!
LinkedIn:www.linkedin.com/in/vahid-dm/

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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