Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
I am using the following code to pull in data from an API in a Power BI Dataflow
Json.Document(Web.Contents("https://"&APIEnvironment&"/path/" & "?limit=100", [ Headers=[Authorization="Bearer " & #"AccessToken"]]))
This pulls back a column with nested record which I can expand.
As an alternative is there anyway of not expanding the nested records and just having the pulled back field as a JSON type. I would like to then connect to the dataflow and expand the JSON type in the Power Query in the desktop version.
Solved! Go to Solution.
No. I am not aware of any way to return embedded lists, records, etc. in a loaded dataflow.
This simple table:
let
Source = #table(
{"ID", "Name", "City"},
{
{123, "Alice", {1.10}},
{456, "Bob", {100.150}}
}
)
in
Source
has a nested list in the third column. When that is loaded in a dataflow nothing comes through into Power BI's Power Query. it is just a blank field.
You will need to do the expansion in the dataflow, or connect to the JSON directy from Power BI's Power Query if you want to expand it there.
DAX is for Analysis. Power Query is for Data Modeling
Proud to be a Super User!
MCSA: BI ReportingI faced the same issue and struggled to have the pulled back field as a JSON type. Eventually, I ended up converting the JSON into text type (jsontext variable below) using the code below. The text can then be parsed and transformed into JSON using Power Query GUI.
let
Source = Query(),
jsontext = Text.FromBinary(Json.FromValue(Source)),
#"Convert to table" = Table.FromValue(jsontext),
#"Changed column type" = Table.TransformColumnTypes(#"Convert to table", {{"Value", type text}})
in
#"Changed column type"
let
Source = () as list =>
let
Token = "token"
body = Text.ToBinary("{""limit"":1000000}"),
actualUrl = "url",
options = [RelativePath="relative_path" ,
Headers =[#"Content-type"="application/json",Authorization="Bearer "&""& Token &""],
Content= body
],
result = Web.Contents(actualUrl, options),
#"Imported JSON" = Json.Document(result, 65001)
in
#"Imported JSON"
in
Source
No. I am not aware of any way to return embedded lists, records, etc. in a loaded dataflow.
This simple table:
let
Source = #table(
{"ID", "Name", "City"},
{
{123, "Alice", {1.10}},
{456, "Bob", {100.150}}
}
)
in
Source
has a nested list in the third column. When that is loaded in a dataflow nothing comes through into Power BI's Power Query. it is just a blank field.
You will need to do the expansion in the dataflow, or connect to the JSON directy from Power BI's Power Query if you want to expand it there.
DAX is for Analysis. Power Query is for Data Modeling
Proud to be a Super User!
MCSA: BI ReportingThis is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
15 | |
12 | |
8 | |
8 | |
7 |
User | Count |
---|---|
15 | |
13 | |
9 | |
7 | |
6 |