需求:
MSSQL,列出服 例中所有 的如下信息: ID、 名、 建日期、 文件 型、 文件大小、 大小、文件所在路 。
法(後面的百分比 所花 占比):
-- 连接子查询 (47%)
WITH cte_TotalSize AS
(
SELECT database_id
,CAST(SUM(size) AS FLOAT)/128 AS [TotalSize(MB)]
FROM sys.master_files
GROUP BY database_id
)
SELECT a.database_id AS [DB_ID]
,b.name AS [DB_Name]
,b.create_date
,CASE a.type WHEN 1 THEN 'Log' ELSE 'Data' END AS File_Type
,CAST(a.size AS FLOAT)/128 AS [Size(MB)] -- Size以页(8 KB)为单位
,c.[TotalSize(MB)]
,a.physical_Name AS File_Path
FROM sys.master_files a
INNER JOIN sys.databases b ON a.database_id = b.database_id
INNER JOIN cte_TotalSize c ON a.database_id = c.database_id
-- 标题子查询 (34%)
SELECT a.database_id AS [DB_ID]
,b.name AS [DB_Name]
,b.create_date
,CASE a.type WHEN 1 THEN 'Log' ELSE 'Data' END AS File_Type
,CAST(a.size AS FLOAT)/128 AS [Size(MB)] -- Size以页(8 KB)为单位
,(SELECT CAST(SUM(size) AS FLOAT)/128 FROM sys.master_files WHERE database_id = a.database_id) AS [TotalSize(MB)]
,a.physical_Name AS File_Path
FROM sys.master_files a
INNER JOIN sys.databases b ON a.database_id = b.database_id
-- 窗口函数 (19%)
SELECT a.database_id AS [DB_ID]
,b.name AS [DB_Name]
,b.create_date
,CASE a.type WHEN 1 THEN 'Log' ELSE 'Data' END AS File_Type
,CAST(a.size AS FLOAT)/128 AS [Size(MB)] -- Size以页(8 KB)为单位
,CAST(SUM(size) OVER(PARTITION BY a.database_id) AS FLOAT)/128 AS [TotalSize(MB)]
,a.physical_Name AS File_Path
FROM sys.master_files a
INNER JOIN sys.databases b ON a.database_id = b.database_id
果:

其中第三 是使用了窗口函 ,相 文 :http://msdn.microsoft.com/zh-cn/library/ms189461.aspx