Supply frequency measure...

Matty

Well-known Member
Joined
Feb 17, 2007
Messages
3,717
Hi Team,

Looking for some help to do the following...

Data as follows:

WeekProductSupply
1Apple0
2Apple0
3Apple0
4Apple5
5Apple0
6Apple0
7Apple10
8Apple0
9Apple10
10Apple0
11Apple0
12Apple0
13Apple0
14Apple0
15Apple5
16Apple0
17Apple0
18Apple5
19Apple0
20Apple10
1Banana20
2Banana0
3Banana20
4Banana20
5Banana0
6Banana30
7Banana0
8Banana0
9Banana0
10Banana20
11Banana20
12Banana0
13Banana0
14Banana0
15Banana0
16Banana0
17Banana0
18Banana0
19Banana0
20Banana0

<tbody>
</tbody>

I want a DAX measure to return the following results:

ProductSupply Frequency
Apple3.20
Banana2.00

<tbody>
</tbody>

Which was computed using standard Excel functions as follows:

Code:
=COUNTIF(INDEX(C$2:C$41,MATCH(1,((B$2:B$41=E2)*(C$2:C$41>0)),0)+1):INDEX(C$2:C$41,MATCH(2,1/((B$2:B$41=E2)*(C$2:C$41>0)))),">=0")/COUNTIF(INDEX(C$2:C$41,MATCH(1,((B$2:B$41=E2)*(C$2:C$41>0)),0)+1):INDEX(C$2:C$41,MATCH(2,1/((B$2:B$41=E2)*(C$2:C$41>0)))),">0")

Logic used:

Per product, establish the range of interest by determining the first and last weeks where supply occurred (note that the first week is always moved on by 1 to 'correct' the range for calculation purposes). In the case of 'Apple', a count of 16 is returned (weeks 5 through to 20). Now, divided this number by the number of times supply has occurred over this same time period. For Apple, 5 is returned (supply occurred in weeks 7, 9, 15, 18 and 20). Finally, divide 16 by 5 to get the desired result: 3.2.

Hope this is clear and someone can assist.

Cheers,

Matty
 

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
there are 20 weeks of apples and 6 supply runs. ???
weeks 4,7, 9, 15, 18 and 20

Hi,

See this bit:

Per product, establish the range of interest by determining the first and last weeks where supply occurred (note that the first week is always moved on by 1 to 'correct' the range for calculation purposes)

Hence the range of interest is weeks 5 through to 20.

Cheers,

Matty
 
Upvote 0
Just bumping this in case anyone has any bright ideas...

Cheers,

Matty
 
Upvote 0
Given you haven’t had any response yet, I’ll try to get you started.

LASTNONBLANK and FIRSTNONBLANK, using the date column as the column and a CALCULATE ( SUM ( )) on the Supply column as the expression, will return the last or first date in the current context. If the your data really has 0 rather than blank, you will need to wrap it in a calculate to remove the 0s.
 
Upvote 0
Actually, it’s just a COUNTROWS divided by a MAX minus a MIN, all wrapped in a calculate <> 0
 
Upvote 0
Thanks for the direction, Gaz. :)

Here's what I've come up with:

Code:
Supply Frequency = 
DIVIDE (
    CALCULATE ( LASTNONBLANK ( Table1[Week], [COLOR=#ff0000]0[/COLOR] ), Table1[Supply] <> 0 )
        - CALCULATE ( FIRSTNONBLANK ( Table1[Week], [COLOR=#ff0000]0[/COLOR] ), Table1[Supply] <> 0 ),
    CALCULATE ( COUNTROWS ( Table1 ), Table1[Supply] <> 0 )
        - 1
)

One thing I don't understand is what the 0 highlighted above is actually doing (though the number itself doesn't seem to influence anything - using 6 works just as well!). Can any one help?

Cheers,

Matty
 
Upvote 0
The actual number doesn't matter, just that it is a constant.

LAST/FIRSTNONBLANK look for the last of first blank returned using by the second parameter. Having a constant means that that constant is returned for any date that exists. In hindsight I think you can just replace LAST/FIRSTNONBLANK with Max / Min in this case.

I also think you can wrap the whole thing in the calculate, i.e.

Code:
Supply Frequency = 
CALCULATE (    
    DIVIDE (
        MAX ( Table1[Week] ) - MIN ( Table1[Week] ),
        COUNTROWS ( Table1 ) - 1
    ),
    Table1[Supply] <> 0
)

May be a bit easier to read in the future.
 
Upvote 0
Hi Gaz,

Thanks for explaining the constant bit and providing a much neater formula.

I'm still trying to get my head around how DAX evaluates (the evaluation order seems different to how Excel formulas work). In the formula you've posted, it looks as though the Calculate part is applied first rather than last? What's your understanding of how it's working?

Cheers,

Matty
 
Upvote 0
In some ways they are like excel formulas, but CALCULATE is a notable exception.

Maybe think about CALCULATE with two parameters as:

Code:
CALCULATE (
     {calculate whatever is written here},
     {but imagine you are in a world as defined here}
)
Therefore you need to know the second parameter before you can work out what the first returns.
 
Upvote 0

Forum statistics

Threads
1,214,394
Messages
6,119,262
Members
448,880
Latest member
aveternik

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top