上次说到,既然有Pivot 的行转列,那么肯定也有Unpivot 的列转行 。其实unpivot 处理的情况也是差不多,也是分3步走。
首先也是先演示一下unpivot 的用法
CREATE TABLE #Emp (Name NVARCHAR(50),Mon TIME,Tue TIME,Wed TIME,Thu TIME)INSERT INTO #Emp ( Name, Mon, Tue, Wed, Thu )VALUES ( N'Ken', '8:30', '8:45','9:05','8:55' ), ( N'Joan', '8:25', '8:35', NULL,'9:00' ), ( N'Jack', '8:15', '9:03','9:05','8:38' ), ( N'Bob', '9:30', '8:53','9:01','8:56' ) SELECT * FROM #Emp Name Mon Tue Wed Thu-------------------------------------------------- ---------------- ---------------- ---------------- ----------------Ken 08:30:00.0000000 08:45:00.0000000 09:05:00.0000000 08:55:00.0000000Joan 08:25:00.0000000 08:35:00.0000000 NULL 09:00:00.0000000Jack 08:15:00.0000000 09:03:00.0000000 09:05:00.0000000 08:38:00.0000000Bob 09:30:00.0000000 08:53:00.0000000 09:01:00.0000000 08:56:00.0000000
SELECT * FROM #Emp UNPIVOT( [LoginTime] FOR [WeekDay] IN (Mon,Tue,Wed,Thu)) aName LoginTime WeekDay-------------------------------------------------- ---------------- --------------------------------------------------------------------------------------------------------------------------------Ken 08:30:00.0000000 MonKen 08:45:00.0000000 TueKen 09:05:00.0000000 WedKen 08:55:00.0000000 ThuJoan 08:25:00.0000000 MonJoan 08:35:00.0000000 TueJoan 09:00:00.0000000 ThuJack 08:15:00.0000000 MonJack 09:03:00.0000000 TueJack 09:05:00.0000000 WedJack 08:38:00.0000000 ThuBob 09:30:00.0000000 MonBob 08:53:00.0000000 TueBob 09:01:00.0000000 WedBob 08:56:00.0000000 Thu
解释一下,
UNPIVOT( [LoginTime] FOR [WeekDay] IN (Mon,Tue,Wed,Thu)) 里面 。 WeekDay 是 根据 (Mon,Tue,Wed,Thu) 这4个列聚合起来的新列的名称,而 LoginTime 呢,就是存放 (Mon,Tue,Wed,Thu) 这几个列下面的值的新列名称。用起来还是挺方便的。
然后下面我要讲一下unpivot 的3步新路里程
1、赋值元素。首先是会按照 (Mon,Tue,Wed,Thu ) 4个列进行一个行赋值。生成第一步的虚拟表。就像下面一样
SELECT * FROM #Emp a FULL JOIN (SELECT 'Mon' AS [WeekDay] UNION ALL SELECT 'Tue' AS [WeekDay] UNION ALL SELECT 'Wed' AS [WeekDay] UNION ALL SELECT 'Thu' AS [WeekDay])b ON 1 = 1 得出中间表Name Mon Tue Wed Thu WeekDay-------------------------------------------------- ---------------- ---------------- ---------------- ---------------- -------Bob 09:30:00.0000000 08:53:00.0000000 09:01:00.0000000 08:56:00.0000000 MonBob 09:30:00.0000000 08:53:00.0000000 09:01:00.0000000 08:56:00.0000000 TueBob 09:30:00.0000000 08:53:00.0000000 09:01:00.0000000 08:56:00.0000000 WedBob 09:30:00.0000000 08:53:00.0000000 09:01:00.0000000 08:56:00.0000000 ThuJack 08:15:00.0000000 09:03:00.0000000 09:05:00.0000000 08:38:00.0000000 ThuJack 08:15:00.0000000 09:03:00.0000000 09:05:00.0000000 08:38:00.0000000 WedJack 08:15:00.0000000 09:03:00.0000000 09:05:00.0000000 08:38:00.0000000 TueJack 08:15:00.0000000 09:03:00.0000000 09:05:00.0000000 08:38:00.0000000 MonJoan 08:25:00.0000000 08:35:00.0000000 NULL 09:00:00.0000000 TueJoan 08:25:00.0000000 08:35:00.0000000 NULL 09:00:00.0000000 MonJoan 08:25:00.0000000 08:35:00.0000000 NULL 09:00:00.0000000 WedJoan 08:25:00.0000000 08:35:00.0000000 NULL 09:00:00.0000000 ThuKen 08:30:00.0000000 08:45:00.0000000 09:05:00.0000000 08:55:00.0000000 ThuKen 08:30:00.0000000 08:45:00.0000000 09:05:00.0000000 08:55:00.0000000 MonKen 08:30:00.0000000 08:45:00.0000000 09:05:00.0000000 08:55:00.0000000 TueKen 08:30:00.0000000 08:45:00.0000000 09:05:00.0000000 08:55:00.0000000 Wed
2 提取有效元素。结果类似下面语句生成的结果
;WITH CTE AS(SELECT * FROM #Emp a FULL JOIN (SELECT 'Mon' AS [WeekDay] UNION ALL SELECT 'Tue' AS [WeekDay] UNION ALL SELECT 'Wed' AS [WeekDay] UNION ALL SELECT 'Thu' AS [WeekDay])b ON 1 = 1)SELECT Name,[WeekDay], CASE [WeekDay] WHEN 'Mon' THEN Mon WHEN 'Tue' THEN Tue WHEN 'Wed' THEN Wed WHEN 'Thu' THEN Thu ELSE NULL END AS LoginTime FROM CTE Name WeekDay LoginTime-------------------------------------------------- ------- ----------------Ken Mon 08:30:00.0000000Joan Mon 08:25:00.0000000Jack Mon 08:15:00.0000000Bob Mon 09:30:00.0000000Ken Tue 08:45:00.0000000Joan Tue 08:35:00.0000000Jack Tue 09:03:00.0000000Bob Tue 08:53:00.0000000Ken Wed 09:05:00.0000000Joan Wed NULLJack Wed 09:05:00.0000000Bob Wed 09:01:00.0000000Ken Thu 08:55:00.0000000Joan Thu 09:00:00.0000000Jack Thu 08:38:00.0000000Bob Thu 08:56:00.0000000
3 将Null值元素去除。这个好理解了,中间有Null值的行去除
;WITH CTE AS(SELECT * FROM #Emp a FULL JOIN (SELECT 'Mon' AS [WeekDay] UNION ALL SELECT 'Tue' AS [WeekDay] UNION ALL SELECT 'Wed' AS [WeekDay] UNION ALL SELECT 'Thu' AS [WeekDay])b ON 1 = 1),CTE2 AS (SELECT Name,[WeekDay], CASE [WeekDay] WHEN 'Mon' THEN Mon WHEN 'Tue' THEN Tue WHEN 'Wed' THEN Wed WHEN 'Thu' THEN Thu ELSE NULL END AS LoginTime FROM CTE )SELECT * FROM CTE2 WHERE CTE2.LoginTime IS NOT NULLName WeekDay LoginTime-------------------------------------------------- ------- ----------------Ken Mon 08:30:00.0000000Joan Mon 08:25:00.0000000Jack Mon 08:15:00.0000000Bob Mon 09:30:00.0000000Ken Tue 08:45:00.0000000Joan Tue 08:35:00.0000000Jack Tue 09:03:00.0000000Bob Tue 08:53:00.0000000Ken Wed 09:05:00.0000000Jack Wed 09:05:00.0000000Bob Wed 09:01:00.0000000Ken Thu 08:55:00.0000000Joan Thu 09:00:00.0000000Jack Thu 08:38:00.0000000Bob Thu 08:56:00.0000000
好!然后结果有没有和直接Unpivot 一样呢~揍是一样啦~当然罗~中间语句可能不是我演示的那样,我主要是演示中间的虚拟表~
好!周四了~再坚持一天~就又可以星期六上班班啦!