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

Compete to become Power BI Data Viz World Champion! First round ends August 18th. Get started.

Reply
Bebs
Helper II
Helper II

in PowerQuery can we do calculation and store it in a variable ?

Hello,

In Power Query, I've a huge table.

I'd like to get the max year(field) with a filter (REGION='US')

is it possible to make this calculation, rhen put it in a variable (or something like it)

then be able to use  this variable in a filter of another table (= Table.SelectRows(Source, each ([YEAR] < maxyear)) ?

(I need to avoid join tables)

 

Best regards

2 ACCEPTED SOLUTIONS
PhilipTreacy
Super User
Super User

Hi @Bebs 

 

You can create a new query and write code to get the max year and then use that in your Table.SelectRows, or you can reference the max year directly like this

 

 

= Table.SelectRows(#"Previous Step Name", each [Year] < List.Max(Table.SelectRows(TableA, each ([Region] = "US"))[Year]))

 

 

Where TableA is your table with the years and regions.

 

Please download this PBIX file to see examples of both methods 

 

Regards

 

Phil



Did I answer your question? Then please mark my post as the solution.
If I helped you, click on the Thumbs Up to give Kudos.


Blog :: YouTube Channel :: Connect on Linkedin


Proud to be a Super User!


View solution in original post

Anonymous
Not applicable

Hi @PhilipTreacy ,thanks for the quick reply.You are in the right direction. I'll add further.

Hi @Bebs ,

Please refer to the steps provided by PhilipTreacy .

The Table data is shown below:

vzhouwenmsft_0-1713493486386.png

vzhouwenmsft_1-1713493497437.png

Please follow these steps:

1.Create a Blank Query

vzhouwenmsft_2-1713493558393.png

 

2.Use the following code(Replace your own file paths)

vzhouwenmsft_3-1713493610768.png

 

let
    Source = Excel.Workbook(File.Contents("C:\Users\v-zhouwenbin\Desktop\(1)2024.4.19.xlsx"), null, true),
    Table1_Sheet = Source{[Item="Table1",Kind="Sheet"]}[Data],
    Table2_Sheet = Source{[Item="Table2",Kind="Sheet"]}[Data],
    a = Table.PromoteHeaders(Table1_Sheet, [PromoteAllScalars=true]),
    b = Table.PromoteHeaders(Table2_Sheet, [PromoteAllScalars=true]),
    FilteredRows = Table.SelectRows(a, each [REGION] = "US"),
    maxyear = List.Max(FilteredRows[Year]),
    c = Table.SelectRows(b,each [Year] < maxyear)

    

    
in
    c

 

3.Final output

vzhouwenmsft_4-1713493727417.png

 

View solution in original post

2 REPLIES 2
Anonymous
Not applicable

Hi @PhilipTreacy ,thanks for the quick reply.You are in the right direction. I'll add further.

Hi @Bebs ,

Please refer to the steps provided by PhilipTreacy .

The Table data is shown below:

vzhouwenmsft_0-1713493486386.png

vzhouwenmsft_1-1713493497437.png

Please follow these steps:

1.Create a Blank Query

vzhouwenmsft_2-1713493558393.png

 

2.Use the following code(Replace your own file paths)

vzhouwenmsft_3-1713493610768.png

 

let
    Source = Excel.Workbook(File.Contents("C:\Users\v-zhouwenbin\Desktop\(1)2024.4.19.xlsx"), null, true),
    Table1_Sheet = Source{[Item="Table1",Kind="Sheet"]}[Data],
    Table2_Sheet = Source{[Item="Table2",Kind="Sheet"]}[Data],
    a = Table.PromoteHeaders(Table1_Sheet, [PromoteAllScalars=true]),
    b = Table.PromoteHeaders(Table2_Sheet, [PromoteAllScalars=true]),
    FilteredRows = Table.SelectRows(a, each [REGION] = "US"),
    maxyear = List.Max(FilteredRows[Year]),
    c = Table.SelectRows(b,each [Year] < maxyear)

    

    
in
    c

 

3.Final output

vzhouwenmsft_4-1713493727417.png

 

PhilipTreacy
Super User
Super User

Hi @Bebs 

 

You can create a new query and write code to get the max year and then use that in your Table.SelectRows, or you can reference the max year directly like this

 

 

= Table.SelectRows(#"Previous Step Name", each [Year] < List.Max(Table.SelectRows(TableA, each ([Region] = "US"))[Year]))

 

 

Where TableA is your table with the years and regions.

 

Please download this PBIX file to see examples of both methods 

 

Regards

 

Phil



Did I answer your question? Then please mark my post as the solution.
If I helped you, click on the Thumbs Up to give Kudos.


Blog :: YouTube Channel :: Connect on Linkedin


Proud to be a Super User!


Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

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

August 2025 community update carousel

Fabric Community Update - August 2025

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

Top Solution Authors