Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes! Register now.
Hi @Nolock
I have to take the first and last value of FPR of each year in the table and substract those values
For example for year 2019: 20707.28 (26/12/2019 last date of 2019)-2982.06 (31/03/2019 first date of 2019), and then for the next years that can be infinite ( 2020, 2021 2022, 2023 etc ....)
Solved! Go to Solution.
Hi @OscarSuarez10,
I've developed a short PowerQuery query which extracts the first and last value for every year and then substracts them.
let Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("NcvBCQAxCATAXnyHZTWa5GoJ6b+NE8HvwNwrSiiM+skQlTdSAtZiJUZ4yyyZxGrxkkA2GhOiwLEbVsHBadjy3g8=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [TIME = _t, FPR = _t]), ChangedType = Table.TransformColumnTypes(Source,{{"TIME", type date}, {"FPR", Int64.Type}}), SortedTable = Table.Sort(ChangedType, {"TIME"}), MinYear = Date.Year(Table.First(SortedTable)[TIME]), MaxYear = Date.Year(Table.Last(SortedTable)[TIME]), ListOfYears = {MinYear..MaxYear}, TableFromList = Table.FromColumns({ListOfYears}), ChangedTypeToType = Table.TransformColumnTypes(TableFromList,{{"Column1", Int64.Type}}), RenameColumn = Table.RenameColumns(ChangedTypeToType, {{"Column1", "Year"}}), MinOfYear = Table.AddColumn(RenameColumn, "MinOfYear", (curRecord) => List.First( Table.SelectRows( SortedTable, each Date.Year([TIME]) = curRecord[Year] )[FPR] ), type number ), MaxOfYear = Table.AddColumn(MinOfYear, "MaxfYear", (curRecord) => List.Last( Table.SelectRows( SortedTable, each Date.Year([TIME]) = curRecord[Year] )[FPR] ), type number ), Substract = Table.AddColumn(MaxOfYear, "Last of year - first of year", each [MaxfYear] - [MinOfYear], type number) in Substract
Another possible solution would be to use Group By Year and then extract the first and last value of every group.
Hi @OscarSuarez10,
the (curRecord) => functionBody is an anonymous function which I've used instead of each. Check the following slide, it should explain it.
Hi @OscarSuarez10,
I've developed a short PowerQuery query which extracts the first and last value for every year and then substracts them.
let Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("NcvBCQAxCATAXnyHZTWa5GoJ6b+NE8HvwNwrSiiM+skQlTdSAtZiJUZ4yyyZxGrxkkA2GhOiwLEbVsHBadjy3g8=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [TIME = _t, FPR = _t]), ChangedType = Table.TransformColumnTypes(Source,{{"TIME", type date}, {"FPR", Int64.Type}}), SortedTable = Table.Sort(ChangedType, {"TIME"}), MinYear = Date.Year(Table.First(SortedTable)[TIME]), MaxYear = Date.Year(Table.Last(SortedTable)[TIME]), ListOfYears = {MinYear..MaxYear}, TableFromList = Table.FromColumns({ListOfYears}), ChangedTypeToType = Table.TransformColumnTypes(TableFromList,{{"Column1", Int64.Type}}), RenameColumn = Table.RenameColumns(ChangedTypeToType, {{"Column1", "Year"}}), MinOfYear = Table.AddColumn(RenameColumn, "MinOfYear", (curRecord) => List.First( Table.SelectRows( SortedTable, each Date.Year([TIME]) = curRecord[Year] )[FPR] ), type number ), MaxOfYear = Table.AddColumn(MinOfYear, "MaxfYear", (curRecord) => List.Last( Table.SelectRows( SortedTable, each Date.Year([TIME]) = curRecord[Year] )[FPR] ), type number ), Substract = Table.AddColumn(MaxOfYear, "Last of year - first of year", each [MaxfYear] - [MinOfYear], type number) in Substract
Another possible solution would be to use Group By Year and then extract the first and last value of every group.
That helped me a lot, but I have to choose the max FPR month value and min month FPR value of each year and then substract them...
Okey, Thank You !!
Sorry, I don´t understand, What is "curRecord"?
Hi @OscarSuarez10,
the (curRecord) => functionBody is an anonymous function which I've used instead of each. Check the following slide, it should explain it.
It seaches for the minimum and maximum TIME value of a year and then takes the corresponding FPR value. It is the behaviour from your example. Is it wrong?
Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!
Check out the September 2025 Power BI update to learn about new features.