With Power Query
let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Unpivoted Columns" = Table.UnpivotOtherColumns(Source, {}, "Attribute", "Value"),
#"Added Custom" = Table.AddColumn(#"Unpivoted Columns", "Quantity", each if Text.Contains([Attribute],"Quantity") then [Value] else null),
#"Filled Up" = Table.FillUp(#"Added Custom",{"Quantity"}),
#"Filtered Rows" = Table.SelectRows(#"Filled Up", each not Text.StartsWith([Attribute], "Quantity")),
#"Changed Type" = Table.TransformColumnTypes(#"Filtered Rows",{{"Value", type date}}),
#"Inserted Year" = Table.AddColumn(#"Changed Type", "Year", each Date.Year([Value]), Int64.Type),
#"Grouped Rows" = Table.Group(#"Inserted Year", {"Year"}, {{"Total Quantity", each List.Sum([Quantity]), type number}})
in
#"Grouped Rows"
Power Query is a free AddIn for Excel 2010 and 2013, and is built-in functionality from Excel 2016 onwards (where it is referred to as "Get & Transform Data").
It is a powerful yet simple way of getting, changing and using data from a broad variety of sources, creating steps which may be easily repeated and refreshed. I strongly recommend learning how to use Power Query - it's among the most powerful functionalities of Excel.
- Follow this link to learn how to install Power Query in Excel 2010 / 2013.
- Follow this link for an introduction to Power Query functionality.
- Follow this link for a video which demonstrates how to use Power Query code provided.
Excel 2016 (Windows) 64 bit
|
Q |
R |
1 |
Year |
Total Quantity |
2 |
2022 |
36 |
3 |
2023 |
470 |
4 |
2024 |
73 |
5 |
2025 |
365 |
6 |
2026 |
70 |
Bookmarks