cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
UNAZIR Frequent Visitor
Frequent Visitor

Format JSON into table PowerBI

I want to show data from influxDB on PowerBI through HTTP API end point.
following is the JSON i get from Influx while hitting the url.

   {
            "results": [
                {
                    "statement_id": 0,
                    "series": [
                        {
                            "name": "cpu",
                            "columns": [
                                "time",
                                "value"
                            ],
                            "values": [
                                [
                                    "2018-09-13T11:03:57.1175792Z",
                                    0.64
                                ],
                                [
                                    "2018-09-13T11:09:58.2259457Z",
                                    100
                                ]
                            ]
                        }
                    ]
                }
            ]
        }

when i try to create table from it in PowerBI. it shows all columns in a row

PS: i cant change the JSON

Capture.JPG

 Need Help

1 ACCEPTED SOLUTION

Accepted Solutions
Community Support Team
Community Support Team

Re: Format JSON into table PowerBI

Hi @UNAZIR,

 

Please refer to below Power Query.

let
    Source = Json.Document(File.Contents("C:\Users\xxxx\Desktop\generated.json")),
    #"Converted to Table" = Record.ToTable(Source),
    #"Expanded Value" = Table.ExpandListColumn(#"Converted to Table", "Value"),
    #"Expanded Value2" = Table.ExpandRecordColumn(#"Expanded Value", "Value", {"statement_id", "series"}, {"Value.statement_id", "Value.series"}),
    #"Expanded Value.series" = Table.ExpandListColumn(#"Expanded Value2", "Value.series"),
    #"Expanded Value.series1" = Table.ExpandRecordColumn(#"Expanded Value.series", "Value.series", {"name", "columns", "values"}, {"Value.series.name", "Value.series.columns", "Value.series.values"}),
    #"Expanded Value.series.columns" = Table.ExpandListColumn(#"Expanded Value.series1", "Value.series.columns"),
    #"Expanded Value.series.values" = Table.ExpandListColumn(#"Expanded Value.series.columns", "Value.series.values"),
    #"Expanded Value.series.values1" = Table.ExpandListColumn(#"Expanded Value.series.values", "Value.series.values"),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Value.series.values1",{"Value.series.name", "Value.statement_id", "Name"}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Removed Columns", "Value.series.columns", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Value.series.columns.1", "Value.series.columns.2"}),
    #"Removed Columns1" = Table.RemoveColumns(#"Split Column by Delimiter",{"Value.series.columns.2"}),
    #"Added Custom" = Table.AddColumn(#"Removed Columns1", "Value.custom", each if [Value.series.columns.1]="time" and Value.Is([Value.series.values],Int64.Type) then null else if [Value.series.columns.1]="value" and not Value.Is([Value.series.values],Int64.Type) then null else [Value.series.values]),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom", each [Value.custom] <> null),
    #"Removed Columns2" = Table.RemoveColumns(#"Filtered Rows",{"Value.series.values"}),
    #"Grouped Rows" = Table.Group(#"Removed Columns2", {"Value.series.columns.1"}, {{"all data", each Table.AddIndexColumn(_, "Index",1,1),type table}}),
    #"Expanded all data" = Table.ExpandTableColumn(#"Grouped Rows", "all data", {"Value.custom", "Index"}, {"all data.Value.custom", "all data.Index"}),
    #"Pivoted Column" = Table.Pivot(#"Expanded all data", List.Distinct(#"Expanded all data"[Value.series.columns.1]), "Value.series.columns.1", "all data.Value.custom"),
    #"Renamed Columns" = Table.RenameColumns(#"Pivoted Column",{{"all data.Index", "Index"}})
in
    #"Renamed Columns"

This the result.

1.PNG

 

Best regards,

Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
3 REPLIES 3
Super User
Super User

Re: Format JSON into table PowerBI

Can you post your query from Advanced Editor?


Did I answer your question? Mark my post as a solution!

Proud to be a Datanaut!


UNAZIR Frequent Visitor
Frequent Visitor

Re: Format JSON into table PowerBI

I did not write the query myself i just followed some steps to get this result.
This is the query i got in result.

let
    Source = Json.Document(Web.Contents("http://localhost:8086/query?db=ssi-influx&q=select ""time"",""value"" from ""cpu""")),
    #"Converted to Table2" = Record.ToTable(Source),
    #"Expanded Value" = Table.ExpandListColumn(#"Converted to Table2", "Value"),
    #"Expanded Value2" = Table.ExpandRecordColumn(#"Expanded Value", "Value", {"statement_id", "series"}, {"Value.statement_id", "Value.series"}),
    #"Expanded Value.series" = Table.ExpandListColumn(#"Expanded Value2", "Value.series"),
    #"Expanded Value.series1" = Table.ExpandRecordColumn(#"Expanded Value.series", "Value.series", {"name", "columns", "values"}, {"Value.series.name", "Value.series.columns", "Value.series.values"}),
    #"Expanded Value.series.columns" = Table.ExpandListColumn(#"Expanded Value.series1", "Value.series.columns"),
    #"Expanded Value.series.values" = Table.ExpandListColumn(#"Expanded Value.series.columns", "Value.series.values"),
    #"Expanded Value.series.values1" = Table.ExpandListColumn(#"Expanded Value.series.values", "Value.series.values"),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Value.series.values1",{"Value.series.name", "Value.statement_id", "Name"}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Removed Columns", "Value.series.columns", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Value.series.columns.1", "Value.series.columns.2"}),
    #"Removed Columns1" = Table.RemoveColumns(#"Split Column by Delimiter",{"Value.series.columns.2"}),
    #"Reversed Rows" = Table.ReverseRows(#"Removed Columns1"),
    #"Pivoted Column1" = Table.Pivot(#"Reversed Rows", List.Distinct(#"Reversed Rows"[Value.series.columns]), "Value.series.columns", "Value.series.values", List.Count),
    #"Pivoted Column" = Table.Pivot(#"Pivoted Column1", List.Distinct(#"Pivoted Column1"[Value.series.columns]), "Value.series.columns", "Value.series.values"),
    time = #"Pivoted Column"{0}[time]
in
    time
Community Support Team
Community Support Team

Re: Format JSON into table PowerBI

Hi @UNAZIR,

 

Please refer to below Power Query.

let
    Source = Json.Document(File.Contents("C:\Users\xxxx\Desktop\generated.json")),
    #"Converted to Table" = Record.ToTable(Source),
    #"Expanded Value" = Table.ExpandListColumn(#"Converted to Table", "Value"),
    #"Expanded Value2" = Table.ExpandRecordColumn(#"Expanded Value", "Value", {"statement_id", "series"}, {"Value.statement_id", "Value.series"}),
    #"Expanded Value.series" = Table.ExpandListColumn(#"Expanded Value2", "Value.series"),
    #"Expanded Value.series1" = Table.ExpandRecordColumn(#"Expanded Value.series", "Value.series", {"name", "columns", "values"}, {"Value.series.name", "Value.series.columns", "Value.series.values"}),
    #"Expanded Value.series.columns" = Table.ExpandListColumn(#"Expanded Value.series1", "Value.series.columns"),
    #"Expanded Value.series.values" = Table.ExpandListColumn(#"Expanded Value.series.columns", "Value.series.values"),
    #"Expanded Value.series.values1" = Table.ExpandListColumn(#"Expanded Value.series.values", "Value.series.values"),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Value.series.values1",{"Value.series.name", "Value.statement_id", "Name"}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Removed Columns", "Value.series.columns", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Value.series.columns.1", "Value.series.columns.2"}),
    #"Removed Columns1" = Table.RemoveColumns(#"Split Column by Delimiter",{"Value.series.columns.2"}),
    #"Added Custom" = Table.AddColumn(#"Removed Columns1", "Value.custom", each if [Value.series.columns.1]="time" and Value.Is([Value.series.values],Int64.Type) then null else if [Value.series.columns.1]="value" and not Value.Is([Value.series.values],Int64.Type) then null else [Value.series.values]),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom", each [Value.custom] <> null),
    #"Removed Columns2" = Table.RemoveColumns(#"Filtered Rows",{"Value.series.values"}),
    #"Grouped Rows" = Table.Group(#"Removed Columns2", {"Value.series.columns.1"}, {{"all data", each Table.AddIndexColumn(_, "Index",1,1),type table}}),
    #"Expanded all data" = Table.ExpandTableColumn(#"Grouped Rows", "all data", {"Value.custom", "Index"}, {"all data.Value.custom", "all data.Index"}),
    #"Pivoted Column" = Table.Pivot(#"Expanded all data", List.Distinct(#"Expanded all data"[Value.series.columns.1]), "Value.series.columns.1", "all data.Value.custom"),
    #"Renamed Columns" = Table.RenameColumns(#"Pivoted Column",{{"all data.Index", "Index"}})
in
    #"Renamed Columns"

This the result.

1.PNG

 

Best regards,

Yuliana Gu

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