diff --git a/site/pages/other/database-api/working_with_xml.md b/site/pages/other/database-api/working_with_xml.md index f6418fbe..a09bce8d 100644 --- a/site/pages/other/database-api/working_with_xml.md +++ b/site/pages/other/database-api/working_with_xml.md @@ -32,3 +32,41 @@ select CONVERT(VARCHAR(8000), Fields) from BES_ACTION_DEFS where dbo.fn_IsActionExpired(Fields, GetUTCDate()) = 1 ``` returns up to the first 8000 characters of the Fields XML document for each action that is expired at the current time. + +Because Fields is dynamic and allows for custom entries, there is no one list for all possible Fields. +It is possible to generate a list of all of your current Fields for use in the dbo.fn_ExtractField() function by using the sql code below. Note that you can change dbo.action_defs to dbo.fixlet_defs or to any other tables with the Fields column to get the respective lists of existing Fields. + +``` +-- Select the distinct (unique) values found +SELECT DISTINCT + -- Use the .value() XML method to extract the text content + -- from the first (or only) child node named + -- within the current node (represented by x.Item). + -- Cast this extracted value to VARCHAR(MAX) and alias the + -- resulting column as 'fieldname'. + x.Item.value('(Name)[1]', 'VARCHAR(MAX)') AS fieldname +FROM +( + -- Start of a derived table (subquery) aliased as 'actiondefs' + SELECT + -- The [Fields] column (which is likely stored as text) + -- is first cast to VARBINARY(MAX) and then to the XML data type. + -- This double-cast is a common technique to handle + -- potential encoding issues or data type conflicts (e.g., from TEXT/NTEXT). + -- The resulting XML column is aliased as 'data'. + CAST(CAST([Fields] AS VARBINARY(MAX)) AS XML) AS data + FROM + [BFEnterprise].[dbo].[ACTION_DEFS] -- Specify the source table +) AS actiondefs +-- CROSS APPLY is used to invoke the .nodes() function for EACH row +-- from the 'actiondefs' derived table. +CROSS APPLY + -- The .nodes() method "shreds" the XML in the 'data' column. + -- It finds every node matching the XQuery path '/Object/Fields' + -- (i.e., all nodes that are children of the root node). + -- It returns a new row for each matching node. + -- This new "virtual" table is aliased as 'x', + -- and its single column (containing the XML node) is aliased as 'Item'. + actiondefs.data.nodes('/Object/Fields') AS x(Item); + +```