Wrox Programmer Forums

Need to download code?

View our list of code downloads.

Go Back   Wrox Programmer Forums > SQL Server > SQL Server 2000 > SQL Server 2000
Password Reminder
Register
| FAQ | Members List | Calendar | Search | Today's Posts | Mark Forums Read
SQL Server 2000 General discussion of Microsoft SQL Server -- for topics that don't fit in one of the more specific SQL Server forums. version 2000 only. There's a new forum for SQL Server 2005.
Welcome to the p2p.wrox.com Forums.

You are currently viewing the SQL Server 2000 section of the Wrox Programmer to Programmer discussions. This is a community of tens of thousands of software programmers and website developers including Wrox book authors and readers. As a guest, you can read any forum posting. By joining today you can post your own programming questions, respond to other developers’ questions, and eliminate the ads that are displayed to guests. Registration is fast, simple and absolutely free .
DRM-free e-books 300x50
Reply
 
Thread Tools Search this Thread Display Modes
  #1 (permalink)  
Old April 18th, 2006, 05:00 PM
Registered User
 
Join Date: Apr 2006
Location: , , .
Posts: 2
Thanks: 0
Thanked 0 Times in 0 Posts
Default Week number of the month

I am trying to write a query for following:

To find out the week number of the month. Week number corresponds to the first Sunday of the Month.

For example in Month of January 2006, Week 1 starts on 01/01/06 and ends on 01/07/06.Week 2 starts on 01/08/06 and ends on 01/15/06. and so on.

For month of February Week 1 starts on 02/05/06 and ends on 02/11/06. Week 2 starts on 02/12/06 and ends on 02/18/06 and so on.Since Week 1 for february 2006 starts on 02/05/06, any date before this date i.e. from 02/01/06 through 02/04/06 should give the week number as 5 from previous month which runs from 01/29/06 through 02/04/06.

 I hope this is not confusing.

Thanks

Kavita


Reply With Quote
  #2 (permalink)  
Old April 20th, 2006, 09:51 AM
SQLScott's Avatar
Wrox Author
 
Join Date: Dec 2004
Location: Wellington, FL , USA.
Posts: 338
Thanks: 0
Thanked 2 Times in 2 Posts
Default

Taken from BOL:

USE AdventureWorks;
GO
IF OBJECT_ID (N'dbo.ISOweek', N'FN') IS NOT NULL
    DROP FUNCTION dbo.ISOweek;
GO
CREATE FUNCTION dbo.ISOweek (@DATE datetime)
RETURNS int
WITH EXECUTE AS CALLER
AS
BEGIN
     DECLARE @ISOweek int
     SET @ISOweek= DATEPART(wk,@DATE)+1
          -DATEPART(wk,CAST(DATEPART(yy,@DATE) as CHAR(4))+'0104')
--Special cases: Jan 1-3 may belong to the previous year
     IF (@ISOweek=0)
          SET @ISOweek=dbo.ISOweek(CAST(DATEPART(yy,@DATE)-1
               AS CHAR(4))+'12'+ CAST(24+DATEPART(DAY,@DATE) AS CHAR(2)))+1
--Special case: Dec 29-31 may belong to the next year
     IF ((DATEPART(mm,@DATE)=12) AND
          ((DATEPART(dd,@DATE)-DATEPART(dw,@DATE))>= 28))
          SET @ISOweek=1
     RETURN(@ISOweek)
END;
GO
SET DATEFIRST 1;
SELECT dbo.ISOweek(CONVERT(DATETIME,'04/20/2006',101)) AS 'ISO Week';

Scott

Reply With Quote
  #3 (permalink)  
Old April 22nd, 2006, 05:16 AM
Authorized User
 
Join Date: Jun 2003
Location: , , Norway.
Posts: 95
Thanks: 0
Thanked 0 Times in 0 Posts
Default

Scott, I belive the ISOWeek function gives you the weeknumber of the year, not the month as Kavita asks for.

Gert

Reply With Quote
  #4 (permalink)  
Old April 22nd, 2006, 05:05 PM
SQLScott's Avatar
Wrox Author
 
Join Date: Dec 2004
Location: Wellington, FL , USA.
Posts: 338
Thanks: 0
Thanked 2 Times in 2 Posts
Default

Oops...thanks Gert. Sorry about that Kavita. I misread the original post. I will try and modify the function to return the week number of the month and then repost. Again, my apologies.

Scott

Reply With Quote
  #5 (permalink)  
Old April 24th, 2006, 05:29 PM
Friend of Wrox
 
Join Date: Dec 2005
Location: , AZ, .
Posts: 146
Thanks: 0
Thanked 1 Time in 1 Post
Default

The algorithm is as follows
If the day of week number is greater than the day of month number then this day must belong to a week in the prior month so calculate the DATEDIFF in weeks from the 1st Sunday of the prior month. Then Add 1 to make it the week #

ELSE calculate the DATEDIFF in weeks from the 1st Sunday of the current month . Then Add 1 to make it the week #


CREATE FUNCTION dbo.ufs_FirstofMonth (@theDate DATETIME)
RETURNS DATETIME
AS
BEGIN
    RETURN ( DATEADD(d, (DAY(@theDate)-1) * (-1) ,@theDate ) )
END

GO

CREATE FUNCTION dbo.ufs_FirstSunday (@theDate DATETIME)
RETURNS DATETIME
AS
BEGIN
    RETURN ( DATEADD(d, CASE WHEN DATEPART ( dw , dbo.ufs_FirstofMonth(@theDate)) = 1 THEN 0
                         ELSE 8-DATEPART ( dw , dbo.ufs_FirstofMonth(@theDate))
                        END
                    , dbo.ufs_FirstofMonth(@theDate)) )
END

GO

CREATE FUNCTION dbo.ufs_WeekOfMonth (@theDate DATETIME)
RETURNS INTEGER
AS
BEGIN
    RETURN (CASE WHEN DATEPART ( dw , @theDate) > DAY(@theDate)
                        THEN 1 + DATEDIFF(wk, dbo.ufs_FirstSunday(DATEADD(mm,-1,@theDate)) , @theDate)
                    ELSE 1 + DATEDIFF(wk, dbo.ufs_FirstSunday(@theDate) , @theDate)
            END
             )
END

David Lundell
Principal Consultant and Trainer
www.mutuallybeneficial.com
Reply With Quote
Reply


Thread Tools Search this Thread
Search this Thread:

Advanced Search
Display Modes

Posting Rules
You may not post new threads
You may not post replies
You may not post attachments
You may not edit your posts

BB code is On
Smilies are On
[IMG] code is Off
HTML code is Off
Trackbacks are Off
Pingbacks are On
Refbacks are Off


Similar Threads
Thread Thread Starter Forum Replies Last Post
Converting month name to month number kalyanykk SQL Server 2005 7 August 19th, 2008 10:37 PM
How to send mail for each week/month automatically lakshmi_annayappa ASP.NET 1.0 and 1.1 Professional 1 May 25th, 2007 02:43 AM
Week number to a date pdistant ASP.NET 1.0 and 1.1 Professional 5 August 17th, 2004 07:44 PM
1st Week-Day of the Month ticktack Classic ASP Basics 2 January 19th, 2004 10:01 AM



All times are GMT -4. The time now is 04:13 AM.


Powered by vBulletin®
Copyright ©2000 - 2020, Jelsoft Enterprises Ltd.
© 2013 John Wiley & Sons, Inc.