Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount.
Register nowThe Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.
After long investigation (thanks to fiddler network sniffing) I found a way, to displays the text values (not the numer) of option sets in Power Query:
Change:
OData.Feed("https://xxx.api.crm4.dynamics.com/api/data/v9.1/", null, [Implementation="2.0"]),
To
OData.Feed("https://xxx.api.crm4.dynamics.com/api/data/v9.1/", null, [Implementation="2.0", IncludeAnnotations="OData.Community.Display.V1.FormattedValue"]),
This will load the values from the OData endpoint as MetaData.
After that you can add them as new custom column.
Example for the statuscode field
Name of column: statuscode_meta
Formula: = Value.Metadata([statuscode])[OData.Community.Display.V1.FormattedValue]
I tested this with excel and there it worked fine.
Technical background:
IncludeAnnotations="OData.Community.Display.V1.FormattedValue"] is createing the header
Prefer: odata.include-annotations="OData.Community.Display.V1.FormattedValue"
With this header, the D365 API returns the text value from the option set. See https://docs.microsoft.com/en-us/powerapps/developer/common-data-service/webapi/query-data-web-api
With the Value.Metadata() function, you can create a custom column with the text value.
I tested this with Excel Power Query, but it should work with Power BI as well.
Have fun 🙂
Update:
This works also with related entities.
Excellent Solution!! Thanks so much!
I think this method may be out of date as it did not do anything for me (Sept 2022). For anyone having similar difficulties, this is what I did:
Source = Json.Document(Web.Contents(ServiceRootURL & "/EntityDefinitions(LogicalName='prefix_mytable')/Attributes(LogicalName='prefix_myattribute')/Microsoft.Dynamics.CRM.PicklistAttributeMetadata?$select=LogicalName&$expand=OptionSet($select=Options)"))
You'll need to create the parameter ServiceRootURL to hold the https://xxx.api.crm4.dynamics.com/api/data/v9.2 part.
To easily generate the code you need, try XRMToolBox->Power Query (M) Builder and look under the OptionSets tab. Made my life so much simpler!
Hi @MatthiasMoritz,
That helped me a lot, thanks!
But I can't load the data of all columns as I get an error message because not every field is mandatory. They are blank by default and in some cases no value of an option set needs to be chosen.
Do you have an idea?
Thanks
Jessica
Hi Jessica,
try this:
= if [statuscode] = null then null else Value.Metadata([statuscode])[OData.Community.Display.V1.FormattedValue]
Best Matthias
perfect and quick solution - Thanks a lot!
Hi, @MatthiasMoritz
It should be the same result. Are there any different steps applied to Power Query in Power BI? You may try to update Power BI Desktop to the latest version to see if it helps.
Best Regards
Allan
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.