SQL SERVER 如何读取类型为XML的字段
1、先创建一个测试的临时表:
-- 测试数据-- DROP TABLE #XMLTabCREATE TABLE #XMLTab(colxml XML)INSERT INTO #XMLTab SELECT N'<Record id="1629"> <Exception type="RING_BUFFER_EXCEPTION"> <Task address="0x0062B8E8" /> <Error>9003</Error> <Severity>error</Severity> </Exception> <Exception type="BUFFER_EXCEPTION"> <Task address="0xC452BB39" /> <Error>8008</Error> <Severity>true</Severity> </Exception></Record>'INSERT INTO #XMLTab SELECT N'<Record id="1611"> <Exception type="RING_BUFFER_EXCEPTION"> <Task address="" /> <Error>7803</Error> <Severity>false</Severity> </Exception> <Exception type="BUFFER"> <Task address="0xC4445674" /> <Error>4300</Error> <Severity>right</Severity> </Exception></Record>'SELECT colxml FROM #XMLTab


2、读取XML字段方法有两种,方法一:
SELECT
CONVERT(NVARCHAR(50),colxml.query('data(/Record/@id)')) AS [id]
,CONVERT(NVARCHAR(MAX),colxml.query('data(/Record/Exception/@type)[1]')) AS [type1]
,CONVERT(NVARCHAR(MAX),colxml.query('data(/Record/Exception/Task/@address)[1]')) AS [address1]
,colxml.value('data(/Record/Exception/Error)[1]','varchar(max)') AS [Error1]
,colxml.value('data(/Record/Exception/Severity)[1]','varchar(10)') AS [Severity1]
,CONVERT(NVARCHAR(MAX),colxml.query('data(/Record/Exception/@type)[2]')) AS [type2]
,CONVERT(NVARCHAR(MAX),colxml.query('data(/Record/Exception/Task/@address)[2]')) AS [address2]
,colxml.value('data(/Record/Exception/Error)[2]','varchar(MAX)') AS [Error2]
,colxml.value('data(/Record/Exception/Severity)[2]','varchar(10)') AS [Severity2]
FROM #XMLTab
3、方法二:
SELECT
node.c1.value('(@id)[1]','VARCHAR(50)') AS [id]
,node.c1.value('(Exception/@type)[1]','VARCHAR(50)') AS [type1]
,node.c1.value('(Exception/Task/@address)[1]','VARCHAR(50)') AS [address1]
,node.c1.value('(Exception/Error)[1]','VARCHAR(max)') AS [Error1]
,node.c1.value('(Exception/Severity)[1]','VARCHAR(max)') AS [Severity1]
,node.c1.value('(Exception/@type)[2]','VARCHAR(50)') AS [type2]
,node.c1.value('(Exception/Task/@address)[2]','VARCHAR(50)') AS [address2]
,node.c1.value('(Exception/Error)[2]','VARCHAR(max)') AS [Error2]
,node.c1.value('(Exception/Severity)[2]','VARCHAR(max)') AS [Severity2]
FROM #XMLTab CROSS APPLY colxml.nodes('/Record') as node(c1)
两种方法都可以得到下面的效果:

4、其他的用法,比如:将同一节点下的数据合并为一行,
SELECT
colxml.query('data(/Record/Exception/@type)[1]') AS [type1]
,colxml.query('data(/Record/Exception/@type)[2]') AS [type2]
,colxml.query('data(/Record/Exception/@type)')
,CONVERT(NVARCHAR(MAX),colxml.query('data(/Record/Exception/@type)'))
,REPLACE(CONVERT(NVARCHAR(MAX),colxml.query('data(/Record/Exception/@type)')),' ',',')
FROM #XMLTab

5、 测试合并结果:
SELECT
CONVERT(NVARCHAR(50),colxml.query('data(/Record/@id)')) AS [id]
,REPLACE(CONVERT(NVARCHAR(MAX),colxml.query('data(/Record/Exception/@type)')),' ',',') AS [type]
,REPLACE(CONVERT(NVARCHAR(MAX),colxml.query('data(/Record/Exception/Task/@address)')),' ',',') AS [address]
,REPLACE(CONVERT(NVARCHAR(MAX),colxml.query('data(/Record/Exception/Error)')),' ',',') AS [Error]
,REPLACE(CONVERT(NVARCHAR(MAX),colxml.query('data(/Record/Exception/Severity)')),' ',',') AS [Severity]
FROM #XMLTab
