Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
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?
DAX is for Analysis. Power Query is for Data Modeling
Proud to be a Super User!
MCSA: BI ReportingSolved! Go to Solution.
If i understand the problem correctly
each let myyear=[Year] in Table.SelectRows([All Rows], each [Year] >= myyear))
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.
DAX is for Analysis. Power Query is for Data Modeling
Proud to be a Super User!
MCSA: BI ReportingEDIT: 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?
DAX is for Analysis. Power Query is for Data Modeling
Proud to be a Super User!
MCSA: BI Reportinghello, 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.
DAX is for Analysis. Power Query is for Data Modeling
Proud to be a Super User!
MCSA: BI ReportingThank you so much. This is the solution I've been searching for hours. Didn't know let could be used inside a function.
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
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
42 | |
24 | |
23 | |
20 | |
13 |
User | Count |
---|---|
158 | |
61 | |
60 | |
28 | |
18 |