T-SQL Recipes之Customized Database Objects

时间:2022-02-19 16:18:26

The Problem

创建灵活自定义对象决非是一个简单的任务。比如HR想看每种工作职称在所有年限里面的入职累计情况

The Solution

我们一步一步来拆解吧:

  • 获取入职年限的集合,如1999,2000,2001...etc
  • 根据唯一值来统计每年的入职数量,当然是得用动态PIVOT
  • 然后写进SP里面

示例1:获取年限集合

DECLARE @hire_date_years TABLE
(
hire_date_year NVARCHAR(50)
);
INSERT INTO @hire_date_years
( hire_date_year
)
SELECT DISTINCT
DATEPART(YEAR, Employee.HireDate)
FROM HumanResources.Employee; DECLARE @sql_yearlist NVARCHAR(MAX); SELECT @sql_yearlist = ISNULL(@sql_yearlist, '') + ','
+ QUOTENAME(hire_date_year)
FROM @hire_date_years SET @sql_yearlist = STUFF(@sql_yearlist, 1, 1, '') SELECT @sql_yearlist

示例2 根据唯一值来统计

DECLARE @hire_date_years TABLE
(
hire_date_year NVARCHAR(50)
);
DECLARE @sql_yearlist NVARCHAR(MAX);
DECLARE @sql_command NVARCHAR(MAX); INSERT INTO @hire_date_years
( hire_date_year
)
SELECT DISTINCT
DATEPART(YEAR, Employee.HireDate)
FROM HumanResources.Employee; SELECT @sql_yearlist = ISNULL(@sql_yearlist, '') + N','
+ QUOTENAME(hire_date_year)
FROM @hire_date_years SET @sql_yearlist = STUFF(@sql_yearlist, 1, 1, '') SET @sql_command = N'
WITH employee_data
AS ( SELECT Employee.BusinessEntityID ,
Employee.JobTitle ,
DATEPART(YEAR, Employee.HireDate) AS HireDate_Year
FROM HumanResources.Employee
) SELECT
JobTitle,' + @sql_yearlist + N'
FROM employee_data
PIVOT (COUNT(BusinessEntityID) FOR HireDate_Year IN (' + @sql_yearlist + N')) pivot_data' PRINT @sql_command

示例3: 写进SP里面

IF OBJECT_ID(N'dbo.job_title_year_summary', 'P') IS NOT NULL
BEGIN
DROP PROCEDURE dbo.job_title_year_summary;
END SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO CREATE PROCEDURE job_title_year_summary
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON; DECLARE @hire_date_years TABLE
(
hire_date_year NVARCHAR(50)
);
DECLARE @sql_yearlist NVARCHAR(MAX);
DECLARE @sql_command NVARCHAR(MAX); INSERT INTO @hire_date_years
( hire_date_year
)
SELECT DISTINCT
DATEPART(YEAR, Employee.HireDate)
FROM HumanResources.Employee; SELECT @sql_yearlist = ISNULL(@sql_yearlist, '') + N','
+ QUOTENAME(hire_date_year)
FROM @hire_date_years SET @sql_yearlist = STUFF(@sql_yearlist, 1, 1, '') SET @sql_command = N'
WITH employee_data
AS ( SELECT Employee.BusinessEntityID ,
Employee.JobTitle ,
DATEPART(YEAR, Employee.HireDate) AS HireDate_Year
FROM HumanResources.Employee
) SELECT
JobTitle,' + @sql_yearlist + N'
FROM employee_data
PIVOT (COUNT(BusinessEntityID) FOR HireDate_Year IN (' + @sql_yearlist + N')) pivot_data' PRINT @sql_command;
EXEC sp_executesql @sql_command;
END
GO

有了这个存储过程,以后需要用它时,可以用昨时表来存储它的结果,做后一步的处理。