Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

Reply
Anonymous
Not applicable

plot graphs with multiple dates

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 IDDate 1Turnover 1Date 2Turnover 2Date 3Turnover 3Date 4Turnover 4Date 5Turnover 5Date 6Turnover 6Date 7Turnover 7
10791382010-10-3154035552011-10-3157590172012-10-3161463742013-10-3171374072014-10-3188216322015-10-31108370002016-10-3112383000
14127662011-06-3017455952012-06-3017449352013-06-3020129022014-06-3026460562015-06-3033226892016-06-3033993422017-06-304222377
15531542009-06-3054487152010-06-3046808872011-06-3052582452012-06-3080950002013-06-30110660002014-12-31117700002015-12-312586469
17923042011-06-3015120002012-06-3024770002013-06-3025120002014-06-3024680002015-06-3022730002016-06-3020840002017-06-301903000
1 ACCEPTED SOLUTION
v-jayw-msft
Community Support
Community Support

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"

 

 

Capture.PNG

 

Best Regards,

Jay

Community Support Team _ Jay
If this post helps, then please consider Accept it as the solution
to help the other members find it.

View solution in original post

2 REPLIES 2
v-jayw-msft
Community Support
Community Support

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"

 

 

Capture.PNG

 

Best Regards,

Jay

Community Support Team _ Jay
If this post helps, then please consider Accept it as the solution
to help the other members find it.
amitchandak
Super User
Super User

@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

Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel1

Power BI Monthly Update - May 2024

Check out the May 2024 Power BI update to learn about new features.