When you have spent any length of time working with Dynamics CRM Online/Dynamics 365 for Enterprise (D365E) data programmatically, you become accustomed to how Option Set, State and Status Reason values are presented to you in code. To explain, the application does not store your Option Set value display names within the SQL Server Entity tables; rather, the Option Set Value that has been specified alongside your Label is what is stored as an integer value. That is why you are always mandatorily prompted to provide both values within the application:
The following benefits are realised as a result of how this is setup:
- Option Set Labels can be quickly updated for all records in the application if business requirements were to change.
- Duplicate labels are technically supported (although not recommended).
- As highlighted by marc_c, there is a performance benefit for the platform in using integers for this type of data.
That being said, when working with these field types in code, you do always have to have the application window open or a list of all Labels/Values to hand so that you don’t get too confused… 🙂
I have previously extolled the virtues of the Data Export Service on the blog, and why you should consider it if you have basic integration requirements for your CRM/D365E deployment. One area in which it differs from other products on the market is how it handles the field types discussed above. For example, when exporting data to a SQL database via Scribe Online, new columns are created alongside that contain the “Display Name” (i.e. label value) that correspond to each Option, Status and Status Reason Label. So by running the following query against a Scribe export database:
SELECT DISTINCT statecode, statecode_displayname
FROM dbo.account
We get the best of both worlds - our underlying statecode value and their display names - all in 2 lines of code:
This is a big help, particularly when you are then using the data as part of a report, as no additional transformation steps are required and your underlying SQL query can be kept as compact as possible.
The Data Export Service differs from the above in an understandable way, as display name values for Status, Status Reason and Option Set column values are instead segregated out into their own separate table objects in your Azure SQL database:
OptionSetMetadata
GlobalOptionSetMetadata
StateMetadata
StatusMetadata
Why understandable? If you consider how the application can support multiple languages, then you realise that this can also apply to metadata objects across the application - such as field names, view names and - wouldn’t you have guessed it - Labels too. So when we inspect the OptionSetMetadata table, we can see that the table structure accommodates the storing of labels in multiple languages via the LocalizedLabelLanguageCode field:
Unlike the Scribe Online route above (which I assume only retrieves the Labels that correspond to the user account that authenticates with CRM/D365E), the Data Export Service becomes instantly more desirable if you are required to build multi-language reports referencing CRM/D365E application data.
The issue that you have to reconcile yourself with is that your SQL queries, if being expressed as natively as possible, instantly become a whole lot more complex. For example, to achieve the same results as the query above, it would have to be adapted as follows for the Data Export Service:
SELECT DISTINCT statecode, LocalizedLabel
FROM dbo.account
LEFT JOIN dbo.StateMetadata
ON 'account' = EntityName
AND statecode = [State]
AND '1033' = LocalizedLabelLanguageCode
The above is a very basic example, but if your query is complex - and involves multiple Option Set Values - then you would have to resort to using Common Table Expressions (CTE’s) to accommodate each potential JOIN required to get the information you want.
In these moments, we can look at some of the wider functionality provided as part of SQL Server to develop a solution that will keep things as simple as possible and, in this particular instance, a user-defined function is an excellent candidate to consider. These enable you to perform complex operations against the database platform and encapsulate them within very simply expressed objects that can also accept parameters. The good thing about functions is that they can be used to return table objects and scalar (i.e. single) objects.
Using a scalar function, we can, therefore, remove some of the complexity behind returning Option Set, Status and Status Reason labels by creating a function that returns the correct label, based on input parameters received by the function. You could look at creating a “master” function that, based on the input parameters, queries the correct Metadata table for the information you need; but in this example, we are going to look at creating a function for each type of field - Status, Status Reason, Option Set and Global Option Set.
To do this, connect up to your Data Export Service database and open up a new query window, ensuring that the context is set to the correct database. Paste the following code in the window and then hit Execute:
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
--Create Function to return Global Option Set Labels
CREATE FUNCTION [dbo].[fnGetGlobalOptionSetLabel]
(
@GlobalOptionSetName NVARCHAR(64), --The logical name of the Global Option Set
@Option INT, --The option value to retrieve
@LanguageCode INT --The Language of the label to retrieve. English is 1033. Full list of support languages (Correct as of June 2015) can be found here: https://abedhaniyah.blogspot.co.uk/2015/06/list-of-supported-languages-by.html
)
RETURNS NVARCHAR(256)
AS
BEGIN
DECLARE @Label NVARCHAR(256);
DECLARE @RecordCount INT = (SELECT COUNT(*) FROM dbo.GlobalOptionSetMetadata WHERE OptionSetName = @GlobalOptionSetName AND [Option] = @Option AND LocalizedLabelLanguageCode = @LanguageCode);
IF @RecordCount = 1
SET @Label = (SELECT TOP 1 LocalizedLabel FROM dbo.GlobalOptionSetMetadata WHERE OptionSetName = @GlobalOptionSetName AND [Option] = @Option AND LocalizedLabelLanguageCode = @LanguageCode);
ELSE
SET @Label = CAST('An error has occurred. Could not obtain label for Global Option Set field ' + @GlobalOptionSetName AS INT);
RETURN @Label;
END
GO
--Create Function to return Option Set Labels
CREATE FUNCTION [dbo].[fnGetOptionSetLabel]
(
@EntityName NVARCHAR(64), --The Entity logical name that contains the Option Set field
@OptionSetName NVARCHAR(64), --The logical name of the Option Set field
@Option INT, --The option value to retrieve
@LanguageCode INT --The Language of the label to retrieve. English is 1033. Full list of support languages (Correct as of June 2015) can be found here: https://abedhaniyah.blogspot.co.uk/2015/06/list-of-supported-languages-by.html
)
RETURNS NVARCHAR(256)
AS
BEGIN
DECLARE @Label NVARCHAR(256);
DECLARE @RecordCount INT = (SELECT COUNT(*) FROM dbo.OptionSetMetadata WHERE EntityName = @EntityName AND OptionSetName = @OptionSetName AND [Option] = @Option AND LocalizedLabelLanguageCode = @LanguageCode);
IF @RecordCount = 1
SET @Label = (SELECT TOP 1 LocalizedLabel FROM dbo.OptionSetMetadata WHERE EntityName = @EntityName AND OptionSetName = @OptionSetName AND [Option] = @Option AND LocalizedLabelLanguageCode = @LanguageCode);
ELSE
SET @Label = CAST('An error has occurred. Could not obtain label for Option Set field ' + @OptionSetName AS INT);
RETURN @Label;
END
GO
--Create Function to return Status Labels
CREATE FUNCTION [dbo].[fnGetStateLabel]
(
@EntityName NVARCHAR(64), --The Entity logical name that contains the Status field
@State INT, --The Status option value to retrieve
@LanguageCode INT --The Language of the label to retrieve. English is 1033. Full list of support languages (Correct as of June 2015) can be found here: https://abedhaniyah.blogspot.co.uk/2015/06/list-of-supported-languages-by.html
)
RETURNS NVARCHAR(256)
AS
BEGIN
DECLARE @Label NVARCHAR(256);
DECLARE @RecordCount INT = (SELECT COUNT(*) FROM dbo.StateMetadata WHERE EntityName = @EntityName AND [State] = @State AND LocalizedLabelLanguageCode = @LanguageCode);
IF @RecordCount = 1
SET @Label = (SELECT TOP 1 LocalizedLabel FROM dbo.StateMetadata WHERE EntityName = @EntityName AND [State] = @State AND LocalizedLabelLanguageCode = @LanguageCode);
ELSE
SET @Label = CAST('An error has occurred. Could not obtain State label for entity ' + @EntityName AS INT);
RETURN @Label;
END
GO
--Create Function to return Status Reason Labels
CREATE FUNCTION [dbo].[fnGetStatusLabel]
(
@EntityName NVARCHAR(64), --The Entity logical name that contains the Status Reason field
@Status INT, --The Status Reason option value to retrieve
@LanguageCode INT --The Language of the label to retrieve. English is 1033. Full list of support languages (Correct as of June 2015) can be found here: https://abedhaniyah.blogspot.co.uk/2015/06/list-of-supported-languages-by.html
)
RETURNS NVARCHAR(256)
AS
BEGIN
DECLARE @Label NVARCHAR(256);
DECLARE @RecordCount INT = (SELECT COUNT(*) FROM dbo.StatusMetadata WHERE EntityName = @EntityName AND [Status] = @Status AND LocalizedLabelLanguageCode = @LanguageCode);
IF @RecordCount = 1
SET @Label = (SELECT TOP 1 LocalizedLabel FROM dbo.StatusMetadata WHERE EntityName = @EntityName AND [Status] = @Status AND LocalizedLabelLanguageCode = @LanguageCode);
ELSE
SET @Label = CAST('An error has occurred. Could not obtain Status label for entity ' + @EntityName AS INT);
RETURN @Label;
END
GO
This will then go off and create the functions listed in code, which should then show up under the Programmability folder on your SQL database:
For those who are unsure at what the SQL code is doing, it first attempts to determine if only 1 Label can be found for your appropriate field type, based on the parameters provided. If it is successful, then a value is returned; otherwise, the CAST function is designed to force an error to return back to the caller to indicate that none or more than 1 Option Set value was found. In most cases, this would indicate a typo in the parameters you have specified.
As with anything, the best way to see how something works is in the practice! So if we again look at our previous examples shown in this post, we would utilise the dbo.fnGetStateLabel function as follows to return the correct label in English:
SELECT DISTINCT statecode, dbo.fnGetStateLabel('account', statecode, 1033) AS statecode_displayname
FROM dbo.account
With our results returning as follows:
Now we can expose this through our reports and not worry about having to do any kind of transformation/lookup table to get around the issue. 😁
Attempting to keep things as simple as possible by encapsulating complex functionality into simply and clearly expressed functions is an excellent way of ensuring that code can be kept as streamlined as possible, and also ensures that other colleagues can accomplish complex tasks, even if they do not have in-depth knowledge of Transact-SQL.