Some parts in the output code are omitted for clarity reasons.
Description
This custom UDF is added to process a rowset view over an XML document. This would be used for declarations in because it works as a rowset provider.
Optional parameters and different node types are not supported in this version of the UDF. The element node is processed by default.
Custom UDF overloads
Parameters
XML : A VARCHAR
that represents the readable content of the XML.
PATH : A varchar that contains the pattern of the nodes to be processed as rows.
UDF
Copy CREATE OR REPLACE FUNCTION OPENXML_UDF(XML VARCHAR, PATH VARCHAR)
RETURNS TABLE(VALUE VARIANT)
LANGUAGE SQL
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"udf"}}'
AS
$$
SELECT VALUE from TABLE(FLATTEN(input => XML_JSON_SIMPLE(PARSE_XML(XML)), path => PATH ))
$$;
CREATE OR REPLACE FUNCTION XML_JSON_SIMPLE(XML VARIANT)
RETURNS OBJECT
LANGUAGE JAVASCRIPT
COMMENT = '{"origin":"sf_sc","name":"snowconvert","version":{"major":1, "minor":0},"attributes":{"component":"udf"}}'
AS
$$
function toNormalJSON (xmlJSON) {
var finalres = {};
var name= xmlJSON[ '@' ];
var res = {};
finalres[ name ] = res;
for (var key in xmlJSON)
{
if (key == "@" )
{
res[ "$name" ] = xmlJSON[ "@" ];
}
else if (key == "$" ) {
continue ;
}
else if (key.startsWith( "@" ))
{
// This is an attribute
res[key] = xmlJSON[key];
}
else
{
var elements = xmlJSON[ '$' ]
var value = xmlJSON[key];
res[key] = [];
if (Array.isArray(value))
{
for (var elementKey in value)
{
var currentElement = elements[elementKey];
var fixedElement = toNormalJSON(currentElement);
res[key].push(fixedElement);
}
}
else if (value === 0 )
{
var fixedElement = toNormalJSON(elements);
res[key].push(fixedElement);
}
}
}
return finalres;
}
return toNormalJSON(XML);
$$;
SQL Server
Query Result
Copy DECLARE @idoc INT, @doc VARCHAR ( 1000 );
SET @doc = '
<ROOT>
<Customer CustomerID="VINET" ContactName="Paul Henriot">
<Order CustomerID="VINET" EmployeeID="5" OrderDate="1996-07-04T00:00:00">
<OrderDetail OrderID="10248" ProductID="11" Quantity="12"/>
<OrderDetail OrderID="10248" ProductID="42" Quantity="10"/>
</Order>
</Customer>
<Customer CustomerID="LILAS" ContactName="Carlos Gonzlez">
<Order CustomerID="LILAS" EmployeeID="3" OrderDate="1996-08-16T00:00:00">
<OrderDetail OrderID="10283" ProductID="72" Quantity="3"/>
</Order>
</Customer>
</ROOT>' ;
EXEC sp_xml_preparedocument @idoc OUTPUT, @doc;
SELECT * FROM OPENXML (@idoc, '/ROOT/Customer' , 1 )
WITH (CustomerID VARCHAR ( 10 ), ContactName VARCHAR ( 20 ));
Copy CustomerID | ContactName
----------------------------+
VINET | Paul Henriot
LILAS | Carlos Gonzlez
Snowflake
The following example is isolated into a stored procedure because environment variables only support 256 bytes of storage, and the XML demo code uses more than that limit.
Query Result
Copy DECLARE
IDOC INT;
DOC VARCHAR ( 1000 );
BlockResultSet RESULTSET;
BEGIN
DOC : = '
<ROOT>
<Customer CustomerID="VINET" ContactName="Paul Henriot">
<Order CustomerID="VINET" EmployeeID="5" OrderDate="1996-07-04T00:00:00">
<OrderDetail OrderID="10248" ProductID="11" Quantity="12"/>
<OrderDetail OrderID="10248" ProductID="42" Quantity="10"/>
</Order>
</Customer>
<Customer CustomerID="LILAS" ContactName="Carlos Gonzlez">
<Order CustomerID="LILAS" EmployeeID="3" OrderDate="1996-08-16T00:00:00">
<OrderDetail OrderID="10283" ProductID="72" Quantity="3"/>
</Order>
</Customer>
</ROOT>' ;
!!!RESOLVE EWI!!! /*** SSC-EWI-TS0075 - TRANSLATION FOR BUILT-IN PROCEDURE 'sp_xml_preparedocument' IS NOT CURRENTLY SUPPORTED. ***/ !!!
EXEC sp_xml_preparedocument :IDOC OUTPUT, :DOC;
BlockResultSet : = (
SELECT
Left ( value :Customer['@CustomerID'], '10' ) AS 'CustomerID' ,
Left ( value :Customer['@ContactName'], '20' ) AS 'ContactName'
FROM
OPENXML_UDF(:IDOC, ':ROOT:Customer' ));
RETURN TABLE(BlockResultSet);
END;
Copy CustomerID | ContactName
----------------------------+
VINET | Paul Henriot
LILAS | Carlos Gonzlez
Query Result
Copy SET code = '<ROOT>
<Customer CustomerID="VINET" ContactName="Paul Henriot">
<Order CustomerID="VINET" EmployeeID="5" OrderDate="1996-07-04T00:00:00">
<OrderDetail OrderID="10248" ProductID="11" Quantity="12"/>
</Order>
</Customer>
</ROOT>' ;
SELECT
Left ( value :Customer['@CustomerID'], 10 ) as "CustomerID" ,
Left ( value :Customer['@ContactName'], 20 ) as "ContactName"
FROM TABLE(OPENXML_UDF($code, 'ROOT:Customer' ));
Copy CustomerID | ContactName
----------------------------+
VINET | Paul Henriot
Known Issues
No issues were found.
Related EWIs
Last updated 8 months ago