根据时间段计算工作日的天数(SqlServer),包含节假日的处理

创建节假日表:

USE [XHManage]
GO

/****** Object:  Table [dbo].[Holiday]    Script Date: 02/20/2014 17:51:54 ******/
SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO

CREATE TABLE [dbo].[Holiday](
[Id] [int] IDENTITY(1,1) NOT NULL,
[Name] [nvarchar](50) NOT NULL,
[BeginDate] [datetime] NOT NULL,
[EndDate] [datetime] NOT NULL,
[AddUser] [nvarchar](50) NOT NULL,
[AddTime] [datetime] NOT NULL,
[Exchange] [bit] NOT NULL,
CONSTRAINT [PK_Holiday] PRIMARY KEY CLUSTERED
(
[Id] ASC
)WITH (PAD_INDEX  = OFF, STATISTICS_NORECOMPUTE  = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS  = ON, ALLOW_PAGE_LOCKS  = ON) ON [PRIMARY]
) ON [PRIMARY]

GO

ALTER TABLE [dbo].[Holiday] ADD  CONSTRAINT [DF_Holiday_AddTime]  DEFAULT (getdate()) FOR [AddTime]
GO

ALTER TABLE [dbo].[Holiday] ADD  CONSTRAINT [DF_Holiday_Exchange]  DEFAULT ((0)) FOR [Exchange]
GO

输入数据(2014年国家节假日设置数据):

INSERT INTO [XHManage].[dbo].[Holiday]([Name] ,[BeginDate] ,[EndDate] ,[AddUser] ,[AddTime] ,[Exchange])VALUES(‘元旦’,’2014-1-1′,’2014-1-1′,’admin’,’2014-2-20′,1)
INSERT INTO [XHManage].[dbo].[Holiday]([Name] ,[BeginDate] ,[EndDate] ,[AddUser] ,[AddTime] ,[Exchange])VALUES(‘春节’,’2014-1-31′,’2014-2-6′,’admin’,’2014-2-20′,1)
INSERT INTO [XHManage].[dbo].[Holiday]([Name] ,[BeginDate] ,[EndDate] ,[AddUser] ,[AddTime] ,[Exchange])VALUES(‘清明节’,’2014-4-5′,’2014-4-7′,’admin’,’2014-2-20′,1)
INSERT INTO [XHManage].[dbo].[Holiday]([Name] ,[BeginDate] ,[EndDate] ,[AddUser] ,[AddTime] ,[Exchange])VALUES(‘劳动节’,’2014-5-1′,’2014-5-3′,’admin’,’2014-2-20′,1)
INSERT INTO [XHManage].[dbo].[Holiday]([Name] ,[BeginDate] ,[EndDate] ,[AddUser] ,[AddTime] ,[Exchange])VALUES(‘端午节’,’2014-6-2′,’2014-6-2′,’admin’,’2014-2-20′,1)
INSERT INTO [XHManage].[dbo].[Holiday]([Name] ,[BeginDate] ,[EndDate] ,[AddUser] ,[AddTime] ,[Exchange])VALUES(‘中秋节’,’2014-9-8′,’2014-9-8′,’admin’,’2014-2-20′,1)
INSERT INTO [XHManage].[dbo].[Holiday]([Name] ,[BeginDate] ,[EndDate] ,[AddUser] ,[AddTime] ,[Exchange])VALUES(‘国庆节’,’2014-10-1′,’2014-10-7′,’admin’,’2014-2-20′,1)
INSERT INTO [XHManage].[dbo].[Holiday]([Name] ,[BeginDate] ,[EndDate] ,[AddUser] ,[AddTime] ,[Exchange])VALUES(‘春节调休’,’2014-1-26′,’2014-1-26′,’admin’,’2014-2-20′,1)
INSERT INTO [XHManage].[dbo].[Holiday]([Name] ,[BeginDate] ,[EndDate] ,[AddUser] ,[AddTime] ,[Exchange])VALUES(‘春节调休’,’2014-2-8′,’2014-2-8′,’admin’,’2014-2-20′,1)
INSERT INTO [XHManage].[dbo].[Holiday]([Name] ,[BeginDate] ,[EndDate] ,[AddUser] ,[AddTime] ,[Exchange])VALUES(‘劳动节调休’,’2014-5-4′,’2014-5-4′,’admin’,’2014-2-20′,1)
INSERT INTO [XHManage].[dbo].[Holiday]([Name] ,[BeginDate] ,[EndDate] ,[AddUser] ,[AddTime] ,[Exchange])VALUES(‘国庆节调休 ‘,’2014-9-28′,’2014-9-28′,’admin’,’2014-2-20′,1)
INSERT INTO [XHManage].[dbo].[Holiday]([Name] ,[BeginDate] ,[EndDate] ,[AddUser] ,[AddTime] ,[Exchange])VALUES(‘国庆节调休 ‘,’2014-10-11′,’2014-10-11′,’admin’,’2014-2-20′,1)

 

 

 

go
create function [dbo].[WorkDay]
(
@beginday   datetime,
@endday   datetime
)
returns int
AS
begin
–set   datefirst   1
declare  @caldays   int
declare  @id   int
select   @caldays=0

while  DATEDIFF(d, @beginday,@endday)>=0
begin

if  datepart(dw,@beginday)>1 and datepart(dw,@beginday)<7
begin
SELECT @id=count(*) from Holiday
where @beginday between begindate and DATEADD(s,-1,DATEADD(day,1,enddate)) and [Exchange]=0
if(@id=0)
select   @caldays=@caldays+1
end
else
begin
SELECT @id=count(*) from Holiday
where @beginday between begindate and DATEADD(s,-1,DATEADD(day,1,enddate)) and [Exchange]=1
if(@id>0)
select   @caldays=@caldays+1
end
select   @beginday=dateadd(day,1,@beginday)
end
return   @caldays
end

测试:

go
select dbo.[WorkDay](‘2014-10-1′,’2014-10-31’)as ‘工作日’
select dbo.[WorkDay](‘2014-9-1′,’2014-9-30’)as ‘工作日’
select dbo.[WorkDay](‘2014-9-30′,’2014-9-30’)as ‘工作日’
select dbo.[WorkDay](‘2014-6-1′,’2014-6-30’)as ‘工作日’

赞(0) 打赏
分享到: 更多 (0)

觉得文章有用就打赏一下文章作者

支付宝扫一扫打赏

微信扫一扫打赏