SQL Server 2005下利用XML進行項目的合并與拆分
在通常情況下我們在對相同數值項目進行分組求和,那是相當的簡單的啦,只要把select... group by加聚合函數就行了,可是對于串一類的項目進行合并時就不這么簡單了,同樣分解一個按指定分隔符分隔的串或分析指定位置的串,在下我們通常是創建一個函 數,然后分組或提取就行了,現我們主要討論在下利用xml來完成這個工作。
先來一個簡單點,如下的例子對aaa的相同的項目合并。
------------------------------------------------------------------------
-- Author: HappyFlyStone
-- Date : 2009-01-04 20:57:59
-- Ver: Microsoft SQL Server 2005 - 9.00.2047.00 (Intel X86)
-- Apr 14 2006 01:12:25
-- Copyright (c) 1988-2005 Microsoft Corporation
-- Standard Edition on Windows NT5.0(Build 2195: Service Pack 4)
--
------------------------------------------------------------------------
-- Test Data: tb
IF OBJECT_ID('tb') IS NOT NULL
DROP TABLE tb
Go
CREATE TABLE tb(aaa INT,bbb INT)
Go
INSERT INTO tb
SELECT 1,2 UNION ALL
SELECT 1,3 UNION ALL
SELECT 1,4 UNION ALL
SELECT 2,2 UNION ALL
SELECT 2,5
GO
--查詢1
select aaa,[values]=stuff(replace(replace((select [bbb]
from tb
where aaa=t.aaa for xml AUTO), '"/><tb bbb="',','), '"/>',''),1,9,'')
from tb t
group by aaa
--查詢2
SELECT * FROM(
SELECT DISTINCT aaa
FROM tb
) A
OUTER APPLY(
SELECT [bbb]= STUFF(REPLACE(REPLACE(
( SELECT [bbb] FROM tb N
WHERE aaa = A.aaa
FOR XML AUTO
), '<N bbb="', ','), '"/>', ''), 1, 1, '')
) N
--查詢3
select aaa,[values]=stuff((select ','+ltrim([bbb])
from tb t
where aaa=tb.aaa for xml path('')), 1, 1, '')
from tb
group by aaa
drop table tb
--查詢結果
/*
aaa values
----------- ---------
1 2,3,4
2 2,5
(2 行受影響)
*/
來個兩個表關聯操作并實現行列轉換的
------------------------------------------------------------------------
-- Author: HappyFlyStone
-- Date : 2009-01-04 20:57:59
-- Ver: Microsoft SQL Server 2005 - 9.00.2047.00 (Intel X86)
-- Apr 14 2006 01:12:25
-- Copyright (c) 1988-2005 Microsoft Corporation
-- Standard Edition on Windows NT5.0(Build 2195: Service Pack 4)
--
------------------------------------------------------------------------
-- Test Data: ta
IF OBJECT_ID('ta') IS NOT NULL
DROP TABLE ta
Go
CREATE TABLE ta(pid INT,tid INT,name NVARCHAR(6))
Go
INSERT INTO ta
SELECT 1,1,'hy3500' UNION ALL
SELECT 1,2,'aabbcc' UNION ALL
SELECT 2,3,'1111' UNION ALL
SELECT 2,4,'2222'
GO
-- Test Data: tb
IF OBJECT_ID('tb') IS NOT NULL
DROP TABLE tb
Go
CREATE TABLE tb(NAME NVARCHAR(2),id INT)
Go
INSERT INTO tb
SELECT '型號',1 UNION ALL
SELECT '參數',2
GO
--Start
SELECT t.[name],A,B
FROM(
SELECT B.[NAME], CAST((SELECT [name]
FROM TA
WHERE PID = A.PID FOR XML PATH('')) AS XML) AS X
FROM TA A
LEFT JOIN TB B ON A.PID = B.ID
GROUP BY B.[NAME],A.PID
) t
CROSS APPLY
(SELECT A=t.x.value('/name[1]','VARCHAR(10)'),B = t.x.value('/name[2]','VARCHAR(10)')) M
--Result:
/*
c a b
---- ---------- ----------
參數 1111 2222
型號 hy3500 aabbcc
(2 行受影響)
*/
--End
取特定分隔符分隔的串中指定位置的串
------------------------------------------------------------------------
-- Author: HappyFlyStone
-- Date : 2009-01-04 20:57:59
-- Ver: Microsoft SQL Server 2005 - 9.00.2047.00 (Intel X86)
-- Apr 14 2006 01:12:25
-- Copyright (c) 1988-2005 Microsoft Corporation
-- Standard Edition on Windows NT 5.0 (Build 2195: Service Pack 4)
--
------------------------------------------------------------------------
DECLARE @t TABLE(c VARCHAR(20))
INSERT @t SELECT '雙橋,9.6米,30.0噸'
UNION ALL SELECT 'aa,bb,cc,dd'
--通常情況如果項目在四個項目以內時,推薦一種方法:
SELECT REPLACE(PARSENAME(XX,3),'$$','.') C ,
REPLACE(PARSENAME(XX,2),'$$','.') B
FROM
(
SELECT REPLACE(REPLACE(c,'.','$$'),',','.') XX FROM @T
)AA
--result
/*
c b
--------------------------------- -----------
雙橋 9.6米
(所影響的行數為1 行)
*/
好,那我們來看看下XML如何處理的
SELECT A,B FROM
(SELECT CAST('<r>' + REPLACE(c,',','</r><r>') + '</r>' AS XML) x,c FROM @t) a
CROSS APPLY
(SELECT A=a.x.value('/r[1]','VARCHAR(10)'),B=a.x.value('/r[2]','VARCHAR(10)')) b
/*
A B
---------- ----------
雙橋 9.6米
aa bb
(2 行受影響)
*/
把項目串的編碼用相應名稱代替
------------------------------------------------------------------------
-- Author: HappyFlyStone
-- Date : 2009-01-04 20:57:59
-- Ver: Microsoft SQL Server 2005 - 9.00.2047.00 (Intel X86)
-- Apr 14 2006 01:12:25
-- Copyright (c) 1988-2005 Microsoft Corporation
-- Standard Edition on Windows NT 5.(Build 2195: Service Pack 4)
--
------------------------------------------------------------------------
-- Test Data: ta
IF OBJECT_ID('ta') IS NOT NULL
DROP TABLE ta
Go
CREATE TABLE ta(ID NVARCHAR(3),number varchar(20))
Go
INSERT INTO ta
SELECT '001','1,2' UNION ALL
SELECT '002','1,2,3'
GO
-- Test Data: tb
IF OBJECT_ID('tb') IS NOT NULL
DROP TABLE tb
Go
CREATE TABLE tb(ID INT,name NVARCHAR(7))
Go
INSERT INTO tb
SELECT 1,'測試一' UNION ALL
SELECT 2,'測試二' UNION ALL
SELECT 3,'測試三'
GO
--Start
--查詢一
SELECT C.ID,NUMBER = STUFF(REPLACE(REPLACE((
SELECT B.NAME AS NAME
FROM TA A
LEFT JOIN
( SELECT ID,NAME
FROM TB
) B
ON CHARINDEX(','+LTRIM(B.ID)+',',','+A.NUMBER+',')>0
WHERE A.ID = C.ID
FOR XML AUTO
),'"/><B NAME="',','),'"/>',''),1,9,'')
FROM TA C
--查詢二
SELECT A.ID,NUMBER=STUFF(
(SELECT ','+NAME
FROM TB
WHERE CHARINDEX(','+LTRIM(ID)+',',','+A.NUMBER+',')>0
FOR XML PATH(''),ROOT('R'),TYPE).value('/R[1]','NVARCHAR(MAX)')
,1,1,'')
FROM TA A
--Result:
/*
id number
---- -----------------
001 測試一,測試二
002 測試一,測試二,測試三
(2 行受影響)
*/
--End
最后我們來說說折分吧
如:
/*
id value
----------- -----------
1 aa,bb
2 aaa,bbb,ccc
欲按id,分拆value列, 分拆后結果如下:
id value
----------- --------
1 aa
1 bb
2 aaa
2 bbb
2 ccc
*/
一般我們在下會借助中間生成一個連續的序列,然后和表關聯折分,在下我們可借助CTE生成一個序列然后再拆分
------------------------------------------------------------------------
-- Author: HappyFlyStone
-- Date : 2009-01-04 20:57:59
-- Ver: Microsoft SQL Server 2005 - 9.00.2047.00 (Intel X86)
-- Apr 14 2006 01:12:25
-- Copyright (c) 1988-2005 Microsoft Corporation
-- Standard Edition on Windows NT 5.0Build 2195: Service Pack 4)
------------------------------------------------------------------------
CREATE TABLE TB(ID INT,VALUE VARCHAR(30))
INSERT INTO TB VALUES(1,'AA,BB')
INSERT INTO TB VALUES(2,'AAA,BBB,CCC')
GO
SELECT A.ID, B.VALUE
FROM(
SELECT ID,
[value] = CONVERT(XML,'<ROOT><V>' + REPLACE([VALUE], ',', '</V><V>') + '</V></ROOT>')
FROM tb
)A
OUTER APPLY(
SELECT value = N.v.value('.', 'varchar(100)')
FROM A.[value].nodes('/ROOT/V') N(v)
)B
DROP TABLE tb
--查詢結果
/*
id value
----------- ------------------------------
1 aa
1 bb
2 aaa
2 bbb
2 ccc
(5 行受影響)
*/
關鍵字:SQL Server、項目、合并
新文章:
- CentOS7下圖形配置網絡的方法
- CentOS 7如何添加刪除用戶
- 如何解決centos7雙系統后丟失windows啟動項
- CentOS單網卡如何批量添加不同IP段
- CentOS下iconv命令的介紹
- Centos7 SSH密鑰登陸及密碼密鑰雙重驗證詳解
- CentOS 7.1添加刪除用戶的方法
- CentOS查找/掃描局域網打印機IP講解
- CentOS7使用hostapd實現無AP模式的詳解
- su命令不能切換root的解決方法
- 解決VMware下CentOS7網絡重啟出錯
- 解決Centos7雙系統后丟失windows啟動項
- CentOS下如何避免文件覆蓋
- CentOS7和CentOS6系統有什么不同呢
- Centos 6.6默認iptable規則詳解