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
Anonymous
Not applicable

get value by Category using STARTOFYEAR

Dear,
I'm trying to calculate the annual profitability of IndexKey 2, using the most recent value and the first value of the year. But the variable StartValue is ignoring the filter (FatIndexHistoricalData[IndexKey]=2) and returning the value of index 1 (DateKey 20190102). Can someone help me please?

 

Table:

dataset.JPG

Column:

 

Date = DATE(LEFT(FatIndexHistoricalData[DateKey],4),MID(FatIndexHistoricalData[DateKey],5,2),RIGHT(FatIndexHistoricalData[DateKey],2))

Measure:

 

YTD Profit Index 2 = 

    VAR LastValue = 
        CALCULATE(
            MAX(FatIndexHistoricalData[Value]),
            FILTER(FatIndexHistoricalData,FatIndexHistoricalData[Date]=MAX(FatIndexHistoricalData[Date])&&FatIndexHistoricalData[IndexKey]=2) 
        )

    VAR StartValue = //91840.8
        CALCULATE(
           MAX(FatIndexHistoricalData[Value]),
           FILTER(FatIndexHistoricalData,FatIndexHistoricalData[Date]=STARTOFYEAR(FatIndexHistoricalData[Date])&&FatIndexHistoricalData[IndexKey]=2) // 2 - IBOVESPA
        )

RETURN (LastValue / StartValue) - 1) * 100)

thank you,

Portes, Leo

 

 

 

 

8 REPLIES 8
Ashish_Mathur
Super User
Super User

Hi,

So for IndexKey 2, you are expecting the answers to be 92031.86 and 91840.8.  Am i correct?  Share the link from where i can downlod your PBI file.

 


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
Anonymous
Not applicable


@Ashish_Mathur wrote:

Hi,

So for IndexKey 2, you are expecting the answers to be 92031.86 and 91840.8.  Am i correct?  Share the link from where i can downlod your PBI file.

 


@Ashish_Mathur ,
You are right, see the link below:
Index.pbix

 

Thank you for aswering.

Hi,

You may download my PBI file from here.

Hope this helps.

Untitled.png


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
Anonymous
Not applicable

@Ashish_Mathur ,
Thank you for your help! I've tried a similar solution using FIRSTNONBLANK and LASTNONBLANK, but didn't work because I'm having to calculate the cumulative return always referencing the first value of the year (in this case 91840.8).

I set the value in the variable in the example below to show what I wish to do.

YTD Profit iBovespa = 

    VAR LastValue = 
        CALCULATE(
            MAX(FatIndexHistoricalData[Value]),
            FILTER(FatIndexHistoricalData,FatIndexHistoricalData[Date]=MAX(FatIndexHistoricalData[Date])&&FatIndexHistoricalData[IndexKey]=2) 
        )

    VAR StartValue = 91840.8
//        CALCULATE(
//           MAX(FatIndexHistoricalData[Value]),
//           FILTER(ALL(FatIndexHistoricalData),FatIndexHistoricalData[Date]=STARTOFYEAR(FatIndexHistoricalData[Date])&&FatIndexHistoricalData[IndexKey]=2)
//        )

RETURN (((LastValue / StartValue) - 1) * 100)


Cumulative Return.JPG

 

You are welcome.  So did my post solve your question or not?


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Quick question. For your data, do you have multiple values per date per index, or just the one?  If so, you may be able to get rid of the MAX expression.

 

StartValue = CALCULATE(MAX(FatIndexHistoricalData[Value]),
           CALCULATETABLE(FIRSTDATE(FatIndexHistoricalData[Date]),
           FILTER(ALL(FatIndexHistoricalData), FatIndexHistoricalData[IndexKey]=SELECTEDVALUE(FatIndexHistoricalData[IndexKey]) && YEAR(FatIndexHistoricalData[Date])=YEAR(SELECTEDVALUE(FatIndexHistoricalData[Date])))))

So I think the reason your version isn't working is because STARTOFYEAR (and STARTOFMONTH, etc) have a super fun property I found out about here: https://dax.guide/startofyear/

 

The dates argument can be any of the following:

  • A reference to a date/time column. Only in this case a context transition applies because the column reference is replaced by

 

It turns out that they are actually calculate a table of values at the current context, but because you're applying the IndexKey=2 at the same time, it finds the start of year, but that no longer is linked to an IndexKey.  So I've gone and changed the first date calculation to filter on matching year and matching IndexKey so that you can get the StartValue of any index.  The expression is more complicated, but it gets the value you want.

Cmcmahan
Resident Rockstar
Resident Rockstar

Ah, this is tricky but I figured it out.

 

You don't have a value for Jan 1, 2019 for index =2.  STARTOFYEAR gets a date, and returns Jan 1 with the same year.

 

You're trying to check what the [Value] is when [Date]=1/1/2019, which is null.

Instead of using STARTOFYEAR, use FIRSTDATE and another filter constraint to make sure the year is the same.

Anonymous
Not applicable


@Cmcmahan wrote:

Ah, this is tricky but I figured it out.

 

You don't have a value for Jan 1, 2019 for index =2.  STARTOFYEAR gets a date, and returns Jan 1 with the same year.

 

You're trying to check what the [Value] is when [Date]=1/1/2019, which is null.

Instead of using STARTOFYEAR, use FIRSTDATE and another filter constraint to make sure the year is the same.


@Cmcmahan ,
Well noted, I thought the function returned the first value of the year and not the first date. I'll try to resolve using FIRSTDATE.

Thank you for aswering.

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.