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

Shape the future of the Fabric Community! Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions. Take survey.

Reply
edhans
Super User
Super User

Reference a column to filter a nested table in Power Query?

I am trying to filter a column in a nested table by a column in the query that holds the nested table. 

In the [All Rows] column are nested tables that have the year and main account number and amounts. I only want the amounts that are >= the [Year] column. So you can see what I tried to do:

 

(ignore that both the column I am filtering and the column I am filtering by are both called "Year" as that isn't the problem. Renaming one doesn't fix it)

 

I am getting "Expression.Error: A cyclic reference was encountered during evaluation." which I kinda get. I know how to get the results I want by expanding the column and doing some boolean logic, but I'd really like to get the results inside the nested table before expanding. Any suggestions on the right syntax for this, or is it simply not possible for a nested table to reference an external column from the table the nested table is in?

 

20190924 10_59_59-Years - Power Query Editor.png



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting
1 ACCEPTED SOLUTION
Zubair_Muhammad
Community Champion
Community Champion

@edhans 

 

If i understand the problem correctly

 

each let myyear=[Year]
in
Table.SelectRows([All Rows], each [Year] >= myyear))

View solution in original post

8 REPLIES 8
Zubair_Muhammad
Community Champion
Community Champion

@edhans 

 

If i understand the problem correctly

 

each let myyear=[Year]
in
Table.SelectRows([All Rows], each [Year] >= myyear))

Awesome. Thanks. As I was working through it I was thinking if this were in DAX I'd just create a variable or use EARLIER() to get what I wanted. Didn't occur to me to use a variable in Power Query. I wouldn't have gotton the "each" statements right anyway...

 

Many thanks! Very elegant. 



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

EDIT: Nevermind. Got it! I see now I can have additional commas between the each and let without messing up the Table.AddColumn() function.

 

= Table.AddColumn(Source, "Custom",
each let varIndex = [Index], varCategory = [Category], VarMonth = [Month Number]
in
 Table.SelectRows(Table, each [Index] <= varIndex and [Month Number] = VarMonth and [Category] = varCategory))

 

@Zubair_Muhammad - followup to this. How would you assign two variables? So in the above, say I needed to know the year and account number.

 

 

 

each let myyear=[Year] and let account=[szMainAccount]
in
Table.SelectRows([All Rows], each [Year] >= myyear and [szMainAccount]= account))

 

 

 

You can see my logic, but I've tried various ways to do it and nothing works on the variable assignment. I just get errors. Any guidance?



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

hello, i have the same case. is there any better way to have the same output but with better perfomance...
for my data source, working on nested table like this take a lot of time.

 

Unfortunately not. Nested tables can be a source of performance issues. Not really a big deal on a few thousand records, but when you get into the hundreds of thousands or millions, it can be a show stopper.



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting
Anonymous
Not applicable

Thank you so much. This is the solution I've been searching for hours. Didn't know let could be used inside a function.

artemus
Microsoft Employee
Microsoft Employee

Option 1:

 

each 
   let 
       myyear=[Year],
       account=[szMainAccount]
    in
       Table.SelectRows([All Rows], each [Year] >= myyear and [szMainAccount]= account))

 

Option 2:

 

 

each Table.SelectRows([All Rows], (x) => [Year] >= x[Year] and [szMainAccount]= x[szMainAccount])

 

Note: "each" is shorthand for "(_) =>"

and [Foo] is shorthand for _[Foo]

 

Also:

table[[Foo], [Bar]] => Table.SelectRows(table, {"Foo", "Bar"})

table{0} => First row

table{[Foo = "Bar"]} => Get the row where column Foo has value "Bar", error if not exactly 1 row.

{0 .. 9} => A list from 0 to 9

table{1}? => Get the second row, or null if table does not have 2 rows

table{0}[Name] => Get the value from Name column for the first row

 

Finally, most powerful, complex funcation in  Power query:

Table.View

 

@Zubair_Muhammad 

Was thinking around the same. Thanks for the learnings 🙂

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.