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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
Syndicate_Admin
Administrator
Administrator

Hoe to get a value from JSON

Hi,

 

I need help in accessing a value in a JSON string.

 

I have a column called "ratings_and_unit_endorsements" which has the JASON strings. Here is an example:

[{"expiry_date":"2023-11-29","rating":"ADI","unit":"EXYY"},{"expiry_date":"2023-11-30","rating":"APS","unit":"OMXX"},{"expiry_date":"2023-12-01","rating":"APS","unit":"LTOO"}]

 

I have another column "unit" which has values corresponding to the unit values in the JSON. 

 

How can I create a column with only the expiry_date from the JSON that matches the value in column "unit"? So if the column "unit" has a value "LTOO", the new column would have "2023-12-01".

 

When I use Parse JSON, the new column has lists on each row and those lists contain the records.

 

Here is the Parse JSON:

Table.AddColumn(#"Replaced value", "JSON", each Json.Document([ratings_and_unit_endorsements]), type any)

 

 

1 ACCEPTED SOLUTION

Hi ,

Please try:

List.Select(Json.Document([ratings_and_unit_endorsements]),(record) => record[unit] = [unit]){0}[expiry_date]

vcgaomsft_0-1695718821628.png
All steps:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45Wiq6OUUqtKMgsqoxPSSxJjVGyilEyMjAy1jU01DWyjFHSiVEqSizJzEsHyzi6eIKFSvMyS8ACrhGRkTFKtTp4TDE2wDAlIBjVFH/fiAi8phjpGhgSNMUnxN8faEqskg6YqRQbCwA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ratings_and_unit_endorsements = _t, unit = _t]),
    AddExpiryDate = Table.AddColumn(Source, "Expiry Date", each List.Select(Json.Document([ratings_and_unit_endorsements]),(record) => record[unit] = [unit]){0}[expiry_date])in
    AddExpiryDate

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

View solution in original post

3 REPLIES 3
Syndicate_Admin
Administrator
Administrator

I had to change it slightly so it takes into account both "unit" and "rating" and now it works.

Table.AddColumn(#"Renamed columns", "Expiry Date", each List.Select(Json.Document([ratings_and_unit_endorsements]),(record) => record[unit] = [unit] and record[rating] = [rating]){0}[expiry_date])


Thank you!

Syndicate_Admin
Administrator
Administrator

I'm able to get the desired result with the following:

Table.AddColumn(#"Inserted JSON", "expiry_date", each try
if 
   Record.Field([JSON]{0}, "unit") = [unit] and 
   Record.Field([JSON]{0}, "rating") = [rating] 
then Record.Field([JSON]{0}, "expiry_date") 
else if
   Record.Field([JSON]{1}, "unit") = [unit] and 
   Record.Field([JSON]{1}, "rating") = [rating] 
then Record.Field([JSON]{1}, "expiry_date")
else if
   Record.Field([JSON]{2}, "unit") = [unit] and 
   Record.Field([JSON]{2}, "rating") = [rating] 
then Record.Field([JSON]{2}, "expiry_date")
else if
   Record.Field([JSON]{3}, "unit") = [unit] and 
   Record.Field([JSON]{3}, "rating") = [rating] 
then Record.Field([JSON]{3}, "expiry_date")
else if
   Record.Field([JSON]{4}, "unit") = [unit] and 
   Record.Field([JSON]{4}, "rating") = [rating] 
then Record.Field([JSON]{4}, "expiry_date")
else false
otherwise "")

 

This can probably be done better without hardcoding the indexes but I don't know how. Any ideas?

 

Hi ,

Please try:

List.Select(Json.Document([ratings_and_unit_endorsements]),(record) => record[unit] = [unit]){0}[expiry_date]

vcgaomsft_0-1695718821628.png
All steps:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45Wiq6OUUqtKMgsqoxPSSxJjVGyilEyMjAy1jU01DWyjFHSiVEqSizJzEsHyzi6eIKFSvMyS8ACrhGRkTFKtTp4TDE2wDAlIBjVFH/fiAi8phjpGhgSNMUnxN8faEqskg6YqRQbCwA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ratings_and_unit_endorsements = _t, unit = _t]),
    AddExpiryDate = Table.AddColumn(Source, "Expiry Date", each List.Select(Json.Document([ratings_and_unit_endorsements]),(record) => record[unit] = [unit]){0}[expiry_date])in
    AddExpiryDate

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

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.