The ultimate Microsoft Fabric, Power BI, Azure AI, and SQL learning event: Join us in Stockholm, September 24-27, 2024.
Save €200 with code MSCUST on top of early bird pricing!
Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
hi
I am comparing 2 years of data
I have a matrix and have months across the Top and years down the side. The matrix as standard will total each column.
How can make the matrix like the sample attached where it subtracts one value from another and displays difference and also the difference percentage.
Jan | Feb | Mar | Apr | May | Jun | Jul | Aug | Sep | Oct | Nov | Dec | |
2018 | 1200 | 1300 | 1450 | 1800 | 1900 | 1500 | 1200 | 2000 | 2100 | 2200 | 2500 | 2800 |
2019 | 1300 | 1350 | 1560 | 1700 | 1750 | 1400 | 1100 | 2200 | 2200 | 2500 | 2600 | 3500 |
Diff | 100 | 50 | 110 | -100 | -150 | -100 | -100 | 200 | 100 | 300 | 100 | 700 |
% Diff | 8% | 4% | 8% | -6% | -8% | -7% | -8% | 10% | 5% | 14% | 4% | 25%
|
regards
Michael
Solved! Go to Solution.
Hi @mecr123
Open Edit queries,
Create a new blank query, write code as below in Advanced editor
let Source = Table1, //add columns #"Inserted Year" = Table.AddColumn(Source, "Year", each Date.Year([date]), Int64.Type), #"Inserted Month" = Table.AddColumn(#"Inserted Year", "Month", each Date.Month([date]), Int64.Type), #"Inserted Month Name" = Table.AddColumn(#"Inserted Month", "Month Name", each Text.Start(Date.MonthName([date]),3), type text), #"Removed Columns" = Table.RemoveColumns(#"Inserted Month Name",{"date"}), //filter table #"2017 TABLE"=Table.SelectRows(#"Removed Columns", each ([Year] = 2017)), #"2018 TABLE"=Table.SelectRows(#"Removed Columns", each ([Year] = 2018)), //merge queries #"Merged Queries" = Table.NestedJoin(#"2017 TABLE", {"Month Name"}, #"2018 TABLE", {"Month Name"}, "new", JoinKind.LeftOuter), #"Expanded new" = Table.ExpandTableColumn(#"Merged Queries", "new", {"value"}, {"new.value"}), //Add diff #"Added Custom" = Table.AddColumn(#"Expanded new", "Diff", each [new.value]-[value]), #"Added Custom1" = Table.AddColumn(#"Added Custom", "Diff%", each ([new.value]-[value])/[value]), //diff table #"diff table"=Table.SelectColumns(#"Added Custom1",{"Year", "Month","Month Name", "Diff"}), #"Renamed Columns1" = Table.RenameColumns(#"diff table",{{"Diff", "value"}}), #"Changed Type1" = Table.TransformColumnTypes(#"Renamed Columns1",{{"Year", type text}}), #"Replaced Value1" = Table.ReplaceValue(#"Changed Type1","2017","Diff",Replacer.ReplaceText,{"Year"}), //diff% table #"diff% table"=Table.SelectColumns(#"Added Custom1",{"Year", "Month","Month Name", "Diff%"}), #"Renamed Columns2" = Table.RenameColumns(#"diff% table",{{"Diff%", "value"}}), #"Changed Type2" = Table.TransformColumnTypes(#"Renamed Columns2",{{"Year", type text}}), #"Replaced Value2" = Table.ReplaceValue(#"Changed Type2","2017","Diff%",Replacer.ReplaceText,{"Year"}), //reorder columns #"reorder1"=Table.ReorderColumns(#"2017 TABLE",{"Year", "Month", "Month Name", "value"}), #"reorder2"=Table.ReorderColumns(#"2018 TABLE",{"Year", "Month", "Month Name", "value"}), #"reorder3"=Table.ReorderColumns(#"Replaced Value1",{"Year", "Month", "Month Name", "value"}), #"reorder4"=Table.ReorderColumns(#"Replaced Value2",{"Year", "Month", "Month Name", "value"}), //append queries #"Appended Query" = Table.Combine({#"reorder1", #"reorder2", #"reorder3",#"reorder4"}) in #"Appended Query"
Close&&apply
Create a measure in “Query1” table
Measure = IF(MAX(Query1[Year])="diff%",FORMAT(MAX(Query1[value]),"0.00%"),MAX(Query1[value]))
Sort “month name” column by “month” column
Best Regards
Maggie
Community Support Team _ Maggie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @mecr123
Open Edit queries,
Create a new blank query, write code as below in Advanced editor
let Source = Table1, //add columns #"Inserted Year" = Table.AddColumn(Source, "Year", each Date.Year([date]), Int64.Type), #"Inserted Month" = Table.AddColumn(#"Inserted Year", "Month", each Date.Month([date]), Int64.Type), #"Inserted Month Name" = Table.AddColumn(#"Inserted Month", "Month Name", each Text.Start(Date.MonthName([date]),3), type text), #"Removed Columns" = Table.RemoveColumns(#"Inserted Month Name",{"date"}), //filter table #"2017 TABLE"=Table.SelectRows(#"Removed Columns", each ([Year] = 2017)), #"2018 TABLE"=Table.SelectRows(#"Removed Columns", each ([Year] = 2018)), //merge queries #"Merged Queries" = Table.NestedJoin(#"2017 TABLE", {"Month Name"}, #"2018 TABLE", {"Month Name"}, "new", JoinKind.LeftOuter), #"Expanded new" = Table.ExpandTableColumn(#"Merged Queries", "new", {"value"}, {"new.value"}), //Add diff #"Added Custom" = Table.AddColumn(#"Expanded new", "Diff", each [new.value]-[value]), #"Added Custom1" = Table.AddColumn(#"Added Custom", "Diff%", each ([new.value]-[value])/[value]), //diff table #"diff table"=Table.SelectColumns(#"Added Custom1",{"Year", "Month","Month Name", "Diff"}), #"Renamed Columns1" = Table.RenameColumns(#"diff table",{{"Diff", "value"}}), #"Changed Type1" = Table.TransformColumnTypes(#"Renamed Columns1",{{"Year", type text}}), #"Replaced Value1" = Table.ReplaceValue(#"Changed Type1","2017","Diff",Replacer.ReplaceText,{"Year"}), //diff% table #"diff% table"=Table.SelectColumns(#"Added Custom1",{"Year", "Month","Month Name", "Diff%"}), #"Renamed Columns2" = Table.RenameColumns(#"diff% table",{{"Diff%", "value"}}), #"Changed Type2" = Table.TransformColumnTypes(#"Renamed Columns2",{{"Year", type text}}), #"Replaced Value2" = Table.ReplaceValue(#"Changed Type2","2017","Diff%",Replacer.ReplaceText,{"Year"}), //reorder columns #"reorder1"=Table.ReorderColumns(#"2017 TABLE",{"Year", "Month", "Month Name", "value"}), #"reorder2"=Table.ReorderColumns(#"2018 TABLE",{"Year", "Month", "Month Name", "value"}), #"reorder3"=Table.ReorderColumns(#"Replaced Value1",{"Year", "Month", "Month Name", "value"}), #"reorder4"=Table.ReorderColumns(#"Replaced Value2",{"Year", "Month", "Month Name", "value"}), //append queries #"Appended Query" = Table.Combine({#"reorder1", #"reorder2", #"reorder3",#"reorder4"}) in #"Appended Query"
Close&&apply
Create a measure in “Query1” table
Measure = IF(MAX(Query1[Year])="diff%",FORMAT(MAX(Query1[value]),"0.00%"),MAX(Query1[value]))
Sort “month name” column by “month” column
Best Regards
Maggie
Community Support Team _ Maggie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi Nij
thanks but I don't see how the formula HASONEVALUE will help ? what do yo have in mind ?
thanks
Michael
Hi @mecr123
This would need some transformation for the data model.
Could you clear me if you table has only year 2018, 2019, or many years?
If there are many years in your table,
Do you want to display every two years and their difference by slicer?
Best Regards
Maggie
Community Support Team _ Maggie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi Maggie
Yes I am only only going to load 2 years - 2018 & 2019.
Ideally I would like to display it as I have outlioned as I want to see all months and the comparisons.
thanks for your help
regards
Michael
Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.
Check out the August 2024 Power BI update to learn about new features.
User | Count |
---|---|
112 | |
79 | |
74 | |
50 | |
40 |
User | Count |
---|---|
139 | |
119 | |
74 | |
64 | |
63 |