Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
So I have a table with multiple dates and values.
I want those dates on a shared axis and want to plot a line plot.
X-Axis should have Year (Date)
Y-Axis should have Turnovers (Values)
how can this be done?
data example:
Companies House ID | Date 1 | Turnover 1 | Date 2 | Turnover 2 | Date 3 | Turnover 3 | Date 4 | Turnover 4 | Date 5 | Turnover 5 | Date 6 | Turnover 6 | Date 7 | Turnover 7 |
1079138 | 2010-10-31 | 5403555 | 2011-10-31 | 5759017 | 2012-10-31 | 6146374 | 2013-10-31 | 7137407 | 2014-10-31 | 8821632 | 2015-10-31 | 10837000 | 2016-10-31 | 12383000 |
1412766 | 2011-06-30 | 1745595 | 2012-06-30 | 1744935 | 2013-06-30 | 2012902 | 2014-06-30 | 2646056 | 2015-06-30 | 3322689 | 2016-06-30 | 3399342 | 2017-06-30 | 4222377 |
1553154 | 2009-06-30 | 5448715 | 2010-06-30 | 4680887 | 2011-06-30 | 5258245 | 2012-06-30 | 8095000 | 2013-06-30 | 11066000 | 2014-12-31 | 11770000 | 2015-12-31 | 2586469 |
1792304 | 2011-06-30 | 1512000 | 2012-06-30 | 2477000 | 2013-06-30 | 2512000 | 2014-06-30 | 2468000 | 2015-06-30 | 2273000 | 2016-06-30 | 2084000 | 2017-06-30 | 1903000 |
Solved! Go to Solution.
Hi @Anonymous ,
In Power Query Advance Editor:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("bZJLDsIwDETv0jVI4799FsT9r0GqNE4FSN30yU7fTPp6HYQokjweB4PwHI/QeDGFmNnEtHFYgWJibuykLqETS+OgAXFNa+NMJhee2BoTUgLA5L45S8rJ34+hq8ThvrzgTzkXKNSsbHndsJbY8lr4nCnw8mrs6jBfXguLMHvW0tq4SvQ6JBorM0vElDUTslkLqkdMNYNsVd6bnsiM72jGlqw/0RJlXdaORgT35qNzvkqkOLtFl37xcfhIXVM3igX6060R9+YWYI34I8D36Vu3Z7r9+cYccrvyfUGpjXe3VJg/wvsD", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Companies House ID" = _t, #"Date 1" = _t, #"Turnover 1" = _t, #"Date 2" = _t, #"Turnover 2" = _t, #"Date 3" = _t, #"Turnover 3" = _t, #"Date 4" = _t, #"Turnover 4" = _t, #"Date 5" = _t, #"Turnover 5" = _t, #"Date 6" = _t, #"Turnover 6" = _t, #"Date 7" = _t, #"Turnover 7" = _t]),
#"Reordered Columns" = Table.ReorderColumns(Source,{"Companies House ID", "Date 1", "Date 2", "Date 3", "Date 4", "Date 5", "Date 6", "Date 7", "Turnover 1", "Turnover 2", "Turnover 3", "Turnover 4", "Turnover 5", "Turnover 6", "Turnover 7"}),
#"Changed Type" = Table.TransformColumnTypes(#"Reordered Columns",{{"Companies House ID", Int64.Type}, {"Date 1", type date}, {"Date 2", type date}, {"Date 3", type date}, {"Date 4", type date}, {"Date 5", type date}, {"Date 6", type date}, {"Date 7", type date}, {"Turnover 1", Int64.Type}, {"Turnover 2", Int64.Type}, {"Turnover 3", Int64.Type}, {"Turnover 4", Int64.Type}, {"Turnover 5", Int64.Type}, {"Turnover 6", Int64.Type}, {"Turnover 7", Int64.Type}}),
Count = 7,
DATES = List.FirstN(List.Skip(Table.ColumnNames(#"Changed Type")),Count),
Tables = let Cols = Table.ToColumns(#"Changed Type"), st = Cols{0}, cols = List.Zip(List.Split(List.Skip(Cols),Count)) in List.Transform(cols, each Table.FromColumns({st} & _, {"Companies House ID","Date","Turnover"})),
#"Added DATES" = Table.Combine(List.Transform({0..Count-1}, each Table.AddColumn(Tables{_}, "DATES", (r) => DATES{_}))),
#"Removed Columns" = Table.RemoveColumns(#"Added DATES",{"DATES"})
in
#"Removed Columns"
Best Regards,
Jay
Hi @Anonymous ,
In Power Query Advance Editor:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("bZJLDsIwDETv0jVI4799FsT9r0GqNE4FSN30yU7fTPp6HYQokjweB4PwHI/QeDGFmNnEtHFYgWJibuykLqETS+OgAXFNa+NMJhee2BoTUgLA5L45S8rJ34+hq8ThvrzgTzkXKNSsbHndsJbY8lr4nCnw8mrs6jBfXguLMHvW0tq4SvQ6JBorM0vElDUTslkLqkdMNYNsVd6bnsiM72jGlqw/0RJlXdaORgT35qNzvkqkOLtFl37xcfhIXVM3igX6060R9+YWYI34I8D36Vu3Z7r9+cYccrvyfUGpjXe3VJg/wvsD", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Companies House ID" = _t, #"Date 1" = _t, #"Turnover 1" = _t, #"Date 2" = _t, #"Turnover 2" = _t, #"Date 3" = _t, #"Turnover 3" = _t, #"Date 4" = _t, #"Turnover 4" = _t, #"Date 5" = _t, #"Turnover 5" = _t, #"Date 6" = _t, #"Turnover 6" = _t, #"Date 7" = _t, #"Turnover 7" = _t]),
#"Reordered Columns" = Table.ReorderColumns(Source,{"Companies House ID", "Date 1", "Date 2", "Date 3", "Date 4", "Date 5", "Date 6", "Date 7", "Turnover 1", "Turnover 2", "Turnover 3", "Turnover 4", "Turnover 5", "Turnover 6", "Turnover 7"}),
#"Changed Type" = Table.TransformColumnTypes(#"Reordered Columns",{{"Companies House ID", Int64.Type}, {"Date 1", type date}, {"Date 2", type date}, {"Date 3", type date}, {"Date 4", type date}, {"Date 5", type date}, {"Date 6", type date}, {"Date 7", type date}, {"Turnover 1", Int64.Type}, {"Turnover 2", Int64.Type}, {"Turnover 3", Int64.Type}, {"Turnover 4", Int64.Type}, {"Turnover 5", Int64.Type}, {"Turnover 6", Int64.Type}, {"Turnover 7", Int64.Type}}),
Count = 7,
DATES = List.FirstN(List.Skip(Table.ColumnNames(#"Changed Type")),Count),
Tables = let Cols = Table.ToColumns(#"Changed Type"), st = Cols{0}, cols = List.Zip(List.Split(List.Skip(Cols),Count)) in List.Transform(cols, each Table.FromColumns({st} & _, {"Companies House ID","Date","Turnover"})),
#"Added DATES" = Table.Combine(List.Transform({0..Count-1}, each Table.AddColumn(Tables{_}, "DATES", (r) => DATES{_}))),
#"Removed Columns" = Table.RemoveColumns(#"Added DATES",{"DATES"})
in
#"Removed Columns"
Best Regards,
Jay
@Anonymous , First Unpivot the all columns other than Companies House ID, You will get attributes and value
Then split attributes using split by delimiters .
You will get date/turnover in one column. and 1,2,3,4 in another column
delete the later one. Then Pivot the attribute(part 1) and value again, You should get date and turnover
User | Count |
---|---|
73 | |
69 | |
36 | |
26 | |
24 |
User | Count |
---|---|
97 | |
92 | |
54 | |
45 | |
41 |