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
RiskyBiscuts
Advocate I
Advocate I

Look up a value of a cell in the same column and using it in a DAX formula

Good Day, I have been struggling with transforming an Excel workbook into Power BI Desktop. The custom column is "Pop. per Density", and its an animal "Population" divided by a denominator. That denominator is the Median of the "Pop. Density" if the animal in the row matches the the animals in the "Animal" column.

 

Excel Formula:

Pop. per Density = IFERROR([@Population]/MEDIAN(IF([Animal]=[@Animal],[Pop. Density],"")),"")

 

I am still a novice with DAX, but in Excel the formula is straight forward. I just have no idea on how to reference a cell in a column, in PBI, and I cant seem to find a troubleshoot on that either.

 

Pop. per DensityIF( ISERROR( SEARCH("Cat", 'Animals'[Animal]) ), 0, CONVERT(MEDIAN( 'Animals'[Pop. Density]), INTEGER))

 

I just want to replace that string "Cat" with the value of the cell. Am I close? 

 

Animal Population Pop. DensityPop. per Density
Cat2.97  
Fox4.5129.020.15
Eagle2.11  
Snake1.34  
Dog5.6218.640.39
Owl0.11  
Dog1.284.540.09
Monkey1.17  
Dog7.6214.300.53
Frog12.45  

 

Any help on the above would be most appreciated!

 

1 ACCEPTED SOLUTION
Fowmy
Super User
Super User

@RiskyBiscuts 

Can you see if the following calculated column solves your problem?

 

 

Pop. per Density = 

var __ani = Animal[Animal ] 
var __deno = 
    CALCULATE(
        MEDIAN( Animal[Pop. Density] ),
        Animal[Animal ] = __ani,
        REMOVEFILTERS(Animal)
    )
var __pop = Animal[Population ]
return
  DIVIDE( __pop , __deno )

 

 

Fowmy_0-1621618779871.png

 

 

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

View solution in original post

5 REPLIES 5
Fowmy
Super User
Super User

@RiskyBiscuts 

Can you see if the following calculated column solves your problem?

 

 

Pop. per Density = 

var __ani = Animal[Animal ] 
var __deno = 
    CALCULATE(
        MEDIAN( Animal[Pop. Density] ),
        Animal[Animal ] = __ani,
        REMOVEFILTERS(Animal)
    )
var __pop = Animal[Population ]
return
  DIVIDE( __pop , __deno )

 

 

Fowmy_0-1621618779871.png

 

 

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

Spot on! Yes this is what I meant to solve. Only thing I need to do is ignore the 0 and null values in the "Pop. per Density", as it turns I get a null value when 50% of the "Pop. Density" values are less then 0 or null. Do you know how I can ignore those 0 and null values? 

@RiskyBiscuts 

If you want to get rid of the blank and zero lines then you will have to create another with filter as follows:

New Animal = FILTER( Animal , Animal[Pop. per Density] <> BLANK() )

Fowmy_0-1621626901995.png


Or, you can create a measure as blanks are automatically hidden

Measure Pop. per Density = 

var __ani = SELECTEDVALUE(Animal[Animal ])
var __deno = 
    CALCULATE(
        MEDIAN( Animal[Pop. Density] ),
        Animal[Animal ] = __ani,
        REMOVEFILTERS(Animal)
    )
var __pop = SELECTEDVALUE(Animal[Population ])
return
DIVIDE( __pop , __deno )

Fowmy_1-1621627094177.png

 

 



 

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

Greg_Deckler
Super User
Super User

@RiskyBiscuts - I think what you want is:

 

 

Pop. per Density Column = 
  MEDIANX(FILTER('Animals',[Animal]=EARLIER('Animals'[Animal])),[Pop. Density])

 

Also, you can find a lot of Excel to DAX translations here: Excel to DAX Translation - Microsoft Power BI Community

 


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

Hey! Thanks for that link, its going to definately help me out!

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.