Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
I have imported the data in PowerBI from Monday.com using below query -
let
Source = Web.Contents("https://api.monday.com/v2",
[
Headers = [
#"Method" = "POST",
#"Content-Type" = "application/json",
#"Authorization" = "Bearer #your input token"
],
Content = Text.ToBinary("{""query"": ""{ boards (ids: #your board id) { items { id name column_values { title text } } } }""}")
]
),
jsonResponse = Json.Document(Source, 65001),
data = jsonResponse[data],
boards = data[boards],
items = List.First(boards)[items],
#"Converted to Table" = Table.FromList(items, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
#"Expanded Column1" = Table.ExpandRecordColumn(#"Converted to Table", "Column1", {"id", "name", "column_values"}, {"id", "name", "column_values"}),
#"Expanded column_values2" = Table.ExpandListColumn(#"Expanded Column1", "column_values"),
#"Expanded column_values1" = Table.ExpandRecordColumn(#"Expanded column_values2", "column_values", {"title", "text"}, {"title", "text"}),
#"Pivoted Column" = Table.Pivot(#"Expanded column_values1", List.Distinct(#"Expanded column_values1"[title]), "title", "text")
in
#"Pivoted Column"
However, I want each value from 'Subitems' and 'Status' on a new row, without duplicating any values.
Solved! Go to Solution.
Hi @sulaxmi ,
Please try:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("jYy7DoMwEAR/ZXX16URCIDWYh9KgSCmRC4OtNCRGxv8vrkmfZqfY0cwzFRdB0zCKm6BtlbXAGOVd0HXEZOJn30IOjMcXzxTfKRwHY4oZr+xSDp7xc1R3TmddybK2r4K+11YpGAZlJRhH/f8qLYuO92TtCQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Subitems = _t, Status = _t, Column1 = _t, Column2 = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Subitems", type text}, {"Status", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Table.Transpose(Table.FromColumns(List.Zip({List.Transform(Text.Split([Subitems],","),Text.Trim),List.Transform(Text.Split([Status],","),Text.Trim)})))),
#"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Subitems", "Status"}),
#"Expanded Custom" = Table.ExpandTableColumn(#"Removed Columns", "Custom", {"Column1", "Column2"}, {"Column1.1", "Column2.1"}),
#"Renamed Columns" = Table.RenameColumns(#"Expanded Custom",{{"Column1.1", "Subitems"}, {"Column2.1", "Status"}})
in
#"Renamed Columns"
Best Regards,
Gao
Community Support Team
If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!
How to get your questions answered quickly -- How to provide sample data in the Power BI Forum -- China Power BI User Group
Hi @sulaxmi, similar approach here:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("jcy9CoMwFIbhW/k48+Ggba2zxh9cROgoGQKJLm1Tktw/PUv3Tu/y8uw7VbWg6xjVTdD32rvAGG0rGAZiMvH1eYYSGMsbW4pnCjkz1ljwKC6V4Bm/R3fnXfYHWVb6IhhHpa6CadI2gnnW5y/I50Ohk6z9Ag==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Subitems = _t, Status = _t, #"Some data" = _t]),
Ad_Custom = Table.AddColumn(Source, "Custom", each List.Transform(
List.Zip(
{
Text.Split([Subitems], ", "),
Text.Split([Status], ", ")
}
),
(x)=> Text.Combine(x, "||")
), type list),
#"Removed Columns" = Table.RemoveColumns(Ad_Custom,{"Subitems", "Status"}),
#"Expanded Custom" = Table.ExpandListColumn(#"Removed Columns", "Custom"),
#"Split Column by Delimiter" = Table.SplitColumn(#"Expanded Custom", "Custom", Splitter.SplitTextByDelimiter("||", QuoteStyle.Csv), {"Subitems", "Status"})
in
#"Split Column by Delimiter"
Hi @sulaxmi ,
Please try:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("jYy7DoMwEAR/ZXX16URCIDWYh9KgSCmRC4OtNCRGxv8vrkmfZqfY0cwzFRdB0zCKm6BtlbXAGOVd0HXEZOJn30IOjMcXzxTfKRwHY4oZr+xSDp7xc1R3TmddybK2r4K+11YpGAZlJRhH/f8qLYuO92TtCQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Subitems = _t, Status = _t, Column1 = _t, Column2 = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Subitems", type text}, {"Status", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Table.Transpose(Table.FromColumns(List.Zip({List.Transform(Text.Split([Subitems],","),Text.Trim),List.Transform(Text.Split([Status],","),Text.Trim)})))),
#"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Subitems", "Status"}),
#"Expanded Custom" = Table.ExpandTableColumn(#"Removed Columns", "Custom", {"Column1", "Column2"}, {"Column1.1", "Column2.1"}),
#"Renamed Columns" = Table.RenameColumns(#"Expanded Custom",{{"Column1.1", "Subitems"}, {"Column2.1", "Status"}})
in
#"Renamed Columns"
Best Regards,
Gao
Community Support Team
If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!
How to get your questions answered quickly -- How to provide sample data in the Power BI Forum -- China Power BI User Group
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Prices go up Feb. 11th.
Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.