SQL Server行转列、不确定列的行转列
本文使用的方法:
1、用Case When
2、PIVOT函数
首先,模拟一张表:
SRE实战 互联网时代守护先锋,助力企业售后服务体系运筹帷幄!一键直达领取阿里云限量特价优惠。CREATE TABLE TempSubjectResult ( StudentName NVARCHAR(50) NOT NULL, StudentSubject NVARCHAR(50) NOT NULL, StudentGrade DECIMAL(4,1) NOT NULL ) INSERT INTO TempSubjectResult(StudentName,StudentSubject,StudentGrade) VALUES ('小姚','语文','80') INSERT INTO TempSubjectResult(StudentName,StudentSubject,StudentGrade) VALUES ('小姚','数学','70') INSERT INTO TempSubjectResult(StudentName,StudentSubject,StudentGrade) VALUES ('小姚','英语','60') INSERT INTO TempSubjectResult(StudentName,StudentSubject,StudentGrade) VALUES ('小明','语文','90') INSERT INTO TempSubjectResult(StudentName,StudentSubject,StudentGrade) VALUES ('小明','数学','95') INSERT INTO TempSubjectResult(StudentName,StudentSubject,StudentGrade) VALUES ('小明','英语','98') SELECT * FROM TempSubjectResult
表数据为:
-----------------------------------------------------------------------------普通版:转置的列确定-----------------------------------------------------------------------------
方法一:Case When
-- 1 Case When普通版 SELECT StudentName 学生名, MAX(CASE WHEN StudentSubject='语文' THEN StudentGrade END) 语文, MAX(CASE WHEN StudentSubject='数学' THEN StudentGrade END) 数学, MAX(CASE WHEN StudentSubject='英语' THEN StudentGrade END) 英语 FROM TempSubjectResult GROUP BY StudentName
方法二:PIVOT函数
SELECT * FROM TempSubjectResult PIVOT(MAX(StudentGrade) FOR StudentSubject IN([语文],[数学],[英语])) T
以上为知道学科有“语文、数学、英语”,如果不确定科目呢?
此时可以用动态SQL查询,请看进阶版
-----------------------------------------------------------------------------升级版:转置的列不确定-----------------------------------------------------------------------------
方法三、 Case When升级版 动态SQL
-- Case When升级版 动态SQL DECLARE @SqlText NVARCHAR(4000)='SELECT StudentName ''学生名'', ' -- SQL头部分 SELECT SELECT @SqlText=@SqlText+' MAX(CASE WHEN StudentSubject='''+StudentSubject+''' THEN StudentGrade END) '''+StudentSubject +''',' FROM (SELECT DISTINCT StudentSubject FROM TempSubjectResult) T -- 拼接CASE WHEN SELECT @SqlText= LEFT(@SqlText,LEN(@SqlText)-1)+' FROM #TempSubjectResult GROUP BY StudentName' -- 拼接 FROM后面部分 PRINT @SqlText EXEC (@SqlText)
方法四、PIVOT升级版 动态SQL
DECLARE @SqlSubject NVARCHAR(4000) SELECT @SqlSubject= STUFF((SELECT ','+'['+StudentSubject+']' FROM (SELECT DISTINCT StudentSubject FROM #TempSubjectResult) T FOR XML PATH('')),1,1,'') -- 获取PIVOT科目 DECLARE @SqlPIVOT NVARCHAR(4000)='SELECT * FROM #TempSubjectResult PIVOT(MAX(StudentGrade) FOR StudentSubject IN('+@SqlSubject+')) T' -- 拼接PIVOT PRINT @SqlPIVOT EXEC (@SqlPIVOT)
以下情况推荐使用动态转换:
1、需要转置的列不确定,比如转置月的天数,月份的天数有28.29.30.31天,不确定
2、需要转置的列非常多时候,不方便一个个写
附:完整代码
-- 创建模拟数据 CREATE TABLE #TempSubjectResult ( StudentName NVARCHAR(50) NOT NULL, StudentSubject NVARCHAR(50) NOT NULL, StudentGrade DECIMAL(4,1) NOT NULL ) INSERT INTO #TempSubjectResult(StudentName,StudentSubject,StudentGrade) VALUES ('小姚','语文','80') INSERT INTO #TempSubjectResult(StudentName,StudentSubject,StudentGrade) VALUES ('小姚','数学','70') INSERT INTO #TempSubjectResult(StudentName,StudentSubject,StudentGrade) VALUES ('小姚','英语','60') INSERT INTO #TempSubjectResult(StudentName,StudentSubject,StudentGrade) VALUES ('小明','语文','90') INSERT INTO #TempSubjectResult(StudentName,StudentSubject,StudentGrade) VALUES ('小明','数学','95') INSERT INTO #TempSubjectResult(StudentName,StudentSubject,StudentGrade) VALUES ('小明','英语','98') SELECT * FROM #TempSubjectResult -- 1 Case When普通版 SELECT StudentName 学生名, MAX(CASE WHEN StudentSubject='语文' THEN StudentGrade END) 语文, MAX(CASE WHEN StudentSubject='数学' THEN StudentGrade END) 数学, MAX(CASE WHEN StudentSubject='英语' THEN StudentGrade END) 英语 FROM #TempSubjectResult GROUP BY StudentName -- 2 PIVOT普通版 SELECT * FROM #TempSubjectResult PIVOT(MAX(StudentGrade) FOR StudentSubject IN([语文],[数学],[英语])) T -- 3 Case When升级版 动态SQL DECLARE @SqlText NVARCHAR(4000)='SELECT StudentName ''学生名'', ' -- SQL头部分 SELECT SELECT @SqlText=@SqlText+' MAX(CASE WHEN StudentSubject='''+StudentSubject+''' THEN StudentGrade END) '''+StudentSubject +''',' FROM (SELECT DISTINCT StudentSubject FROM #TempSubjectResult) T -- 拼接CASE WHEN SELECT @SqlText= LEFT(@SqlText,LEN(@SqlText)-1)+' FROM #TempSubjectResult GROUP BY StudentName' -- 拼接 FROM后面部分 PRINT @SqlText EXEC (@SqlText) -- 4 PIVOT升级版 动态SQL DECLARE @SqlSubject NVARCHAR(4000) SELECT @SqlSubject= STUFF((SELECT ','+'['+StudentSubject+']' FROM (SELECT DISTINCT StudentSubject FROM #TempSubjectResult) T FOR XML PATH('')),1,1,'') -- 获取PIVOT科目 DECLARE @SqlPIVOT NVARCHAR(4000)='SELECT * FROM #TempSubjectResult PIVOT(MAX(StudentGrade) FOR StudentSubject IN('+@SqlSubject+')) T' -- 拼接PIVOT PRINT @SqlPIVOT EXEC (@SqlPIVOT) DROP TABLE #TempSubjectResult

更多精彩