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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
hiolgh
Frequent Visitor

FILTERing a value from a RELATEDTABLE

Hi all

 

I have two tables, 'LGZ Schools' (1) <---> (*) 'CountYourCarbon'.

They're joined as follows: 'LGZ Schools'[_School ID] <---> 'CountYourCarbon'[sfct_letsgozero]

 

'CountYourCarbon' has three fields: [sfct_letsgozero], [CYC Date] and [CYC Score (Tonnes)].

 

I'm trying to read a value from CountYourCarbon into a new column called "Baseline" in LGZ Schools. I want to filter CountYourCarbon for where there's a match on [_School ID]<--->[sfct_letsgozero], which will return between 0 and 2 rows, then filter that for the earliest date in the [CYC Date] field, and then return the value in the field [CYC Score (Tonnes)].

 

The best I've got so far is:

 
Baseline =
    SELECTCOLUMNS(
        FILTER(
            FILTER(
                RELATEDTABLE(CountYourCarbon),
                'CountYourCarbon'[sfct_letsgozero]='LGZ Schools'[_School ID]
                ),
            [CYC Date]=MIN([CYC Date])
        )
        "Baseline",
        [CYC Score (Tonnes)]
    )
 
I'm getting the error "The syntax for '"Baseline"' is incorrect."
 
Can you please advise?
 
Thanks.
2 ACCEPTED SOLUTIONS
techies
Solution Sage
Solution Sage

Hi @hiolgh please try this calculated column

 

Baseline =
VAR RelatedRows =
    FILTER (
        CountYourCarbon,
        CountYourCarbon[sfct_letsgozero] = 'LGZ Schools'[_School ID]
    )
VAR EarliestDate =
    CALCULATE (
        MIN (CountYourCarbon[CYC Date]),
        RelatedRows
    )
RETURN
    CALCULATE (
        MAX (CountYourCarbon[CYC Score (Tonnes)]),
        FILTER (
            RelatedRows,
            CountYourCarbon[CYC Date] = EarliestDate
        )
    )
― Power BI | Microsoft Fabric | PL-300 | DP-600 | Blog: medium.com/@cseprs_54978

View solution in original post

v-pagayam-msft
Community Support
Community Support

Hi @hiolgh ,
Thank you @techies for the prompt response!

Upon reviewing the information provided,I tried to create it locally.
 Try using the below calculated column:

Baseline =
VAR SchoolID = 'LGZ Schools'[_School ID]
VAR FilteredTable =
    FILTER (
        'CountYourCarbon',
        'CountYourCarbon'[sfct_letsgozero] = SchoolID
    )
VAR MinDate =
    CALCULATE (
        MIN ( 'CountYourCarbon'[CYC Date] ),
        FilteredTable
    )
VAR Result =
    CALCULATE (
        MAX ( 'CountYourCarbon'[CYC Score (Tonnes)] ),
        FILTER (
            FilteredTable,
            'CountYourCarbon'[CYC Date] = MinDate
        )
    )
RETURN
    Result

Please refer the screenshot and the file for your reference.
vpagayammsft_0-1746592283582.png


If the solution meets your requirement,consider accepting it as solution.

Thank you for being a part of Microsoft Fabic Community Forum!

Regards,
Pallavi.

View solution in original post

4 REPLIES 4
v-pagayam-msft
Community Support
Community Support

Hi @hiolgh ,
Thank you @techies for the prompt response!

Upon reviewing the information provided,I tried to create it locally.
 Try using the below calculated column:

Baseline =
VAR SchoolID = 'LGZ Schools'[_School ID]
VAR FilteredTable =
    FILTER (
        'CountYourCarbon',
        'CountYourCarbon'[sfct_letsgozero] = SchoolID
    )
VAR MinDate =
    CALCULATE (
        MIN ( 'CountYourCarbon'[CYC Date] ),
        FilteredTable
    )
VAR Result =
    CALCULATE (
        MAX ( 'CountYourCarbon'[CYC Score (Tonnes)] ),
        FILTER (
            FilteredTable,
            'CountYourCarbon'[CYC Date] = MinDate
        )
    )
RETURN
    Result

Please refer the screenshot and the file for your reference.
vpagayammsft_0-1746592283582.png


If the solution meets your requirement,consider accepting it as solution.

Thank you for being a part of Microsoft Fabic Community Forum!

Regards,
Pallavi.

Thanks for taking the time to recreate the tables! 

techies
Solution Sage
Solution Sage

Hi @hiolgh please try this calculated column

 

Baseline =
VAR RelatedRows =
    FILTER (
        CountYourCarbon,
        CountYourCarbon[sfct_letsgozero] = 'LGZ Schools'[_School ID]
    )
VAR EarliestDate =
    CALCULATE (
        MIN (CountYourCarbon[CYC Date]),
        RelatedRows
    )
RETURN
    CALCULATE (
        MAX (CountYourCarbon[CYC Score (Tonnes)]),
        FILTER (
            RelatedRows,
            CountYourCarbon[CYC Date] = EarliestDate
        )
    )
― Power BI | Microsoft Fabric | PL-300 | DP-600 | Blog: medium.com/@cseprs_54978

This is great thanks, and I'll learn from your approach. I had tried using variables but then I couldn't manipulate RelatedRows with further filters. I now see that using it to filter the original table is the way to go.

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

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