Help with this Query

  • I have a date query as below:

    SET DATEFIRST 1 -- Sets Monday as First Day of Week

    ;with mycte as

    (

    select cast('2011-01-01' as datetime) DateValue

    union all

    select DateValue + 1

    from mycte

    where DateValue + 1 < '2013-07-02'

    )

    Select

    DateValue

    ,DATENAME(dw,DateValue) As DayOfWeek

    ,DATENAME(wk,DateValue) As CalendarWeek

    ,Case

    When DATENAME(wk,DateValue) = 27 And Year(DateValue) = 2012 Then 2013

    Else 2012

    End As FinancialYear

    ,Case

    When DATENAME(wk,DateValue) = 27 And Year(DateValue) = 2011 Then 1

    When DATENAME(wk,DateValue) = 28 And Year(DateValue) = 2011 Then 2

    When DATENAME(wk,DateValue) = 29 And Year(DateValue) = 2011 Then 3

    When DATENAME(wk,DateValue) = 29 And Year(DateValue) = 2011 Then 4

    When DATENAME(wk,DateValue) = 30 And Year(DateValue) = 2011 Then 5

    When DATENAME(wk,DateValue) = 31 And Year(DateValue) = 2011 Then 6

    When DATENAME(wk,DateValue) = 32 And Year(DateValue) = 2011 Then 7

    When DATENAME(wk,DateValue) = 33 And Year(DateValue) = 2011 Then 8

    When DATENAME(wk,DateValue) = 34 And Year(DateValue) = 2011 Then 9

    When DATENAME(wk,DateValue) = 35 And Year(DateValue) = 2011 Then 10

    When DATENAME(wk,DateValue) = 36 And Year(DateValue) = 2011 Then 11

    When DATENAME(wk,DateValue) = 37 And Year(DateValue) = 2011 Then 12

    When DATENAME(wk,DateValue) = 38 And Year(DateValue) = 2011 Then 13

    When DATENAME(wk,DateValue) = 39 And Year(DateValue) = 2011 Then 14

    When DATENAME(wk,DateValue) = 40 And Year(DateValue) = 2011 Then 15

    When DATENAME(wk,DateValue) = 41 And Year(DateValue) = 2011 Then 16

    When DATENAME(wk,DateValue) = 42 And Year(DateValue) = 2011 Then 17

    When DATENAME(wk,DateValue) = 43 And Year(DateValue) = 2011 Then 18

    When DATENAME(wk,DateValue) = 44 And Year(DateValue) = 2011 Then 19

    When DATENAME(wk,DateValue) = 45 And Year(DateValue) = 2011 Then 20

    When DATENAME(wk,DateValue) = 46 And Year(DateValue) = 2011 Then 21

    When DATENAME(wk,DateValue) = 47 And Year(DateValue) = 2011 Then 22

    When DATENAME(wk,DateValue) = 48 And Year(DateValue) = 2011 Then 23

    When DATENAME(wk,DateValue) = 49 And Year(DateValue) = 2011 Then 24

    When DATENAME(wk,DateValue) = 50 And Year(DateValue) = 2011 Then 25

    When DATENAME(wk,DateValue) = 51 And Year(DateValue) = 2011 Then 26

    When DATENAME(wk,DateValue) = 52 And Year(DateValue) = 2011 Then 27

    When DATENAME(wk,DateValue) = 53 And Year(DateValue) = 2011 Then 28

    When DATENAME(wk,DateValue) = 1 And Year(DateValue) = 2012 Then 28

    When DATENAME(wk,DateValue) = 2 And Year(DateValue) = 2012 Then 29

    When DATENAME(wk,DateValue) = 3 And Year(DateValue) = 2012 Then 30

    When DATENAME(wk,DateValue) = 4 And Year(DateValue) = 2012 Then 31

    When DATENAME(wk,DateValue) = 5 And Year(DateValue) = 2012 Then 32

    When DATENAME(wk,DateValue) = 6 And Year(DateValue) = 2012 Then 33

    When DATENAME(wk,DateValue) = 7 And Year(DateValue) = 2012 Then 34

    When DATENAME(wk,DateValue) = 8 And Year(DateValue) = 2012 Then 35

    When DATENAME(wk,DateValue) = 9 And Year(DateValue) = 2012 Then 36

    When DATENAME(wk,DateValue) = 10 And Year(DateValue) = 2012 Then 37

    When DATENAME(wk,DateValue) = 11 And Year(DateValue) = 2012 Then 38

    When DATENAME(wk,DateValue) = 12 And Year(DateValue) = 2012 Then 39

    When DATENAME(wk,DateValue) = 13 And Year(DateValue) = 2012 Then 40

    When DATENAME(wk,DateValue) = 14 And Year(DateValue) = 2012 Then 41

    When DATENAME(wk,DateValue) = 15 And Year(DateValue) = 2012 Then 42

    When DATENAME(wk,DateValue) = 16 And Year(DateValue) = 2012 Then 43

    When DATENAME(wk,DateValue) = 17 And Year(DateValue) = 2012 Then 44

    When DATENAME(wk,DateValue) = 18 And Year(DateValue) = 2012 Then 45

    When DATENAME(wk,DateValue) = 19 And Year(DateValue) = 2012 Then 46

    When DATENAME(wk,DateValue) = 20 And Year(DateValue) = 2012 Then 47

    When DATENAME(wk,DateValue) = 21 And Year(DateValue) = 2012 Then 48

    When DATENAME(wk,DateValue) = 22 And Year(DateValue) = 2012 Then 49

    When DATENAME(wk,DateValue) = 23 And Year(DateValue) = 2012 Then 50

    When DATENAME(wk,DateValue) = 24 And Year(DateValue) = 2012 Then 51

    When DATENAME(wk,DateValue) = 25 And Year(DateValue) = 2012 Then 52

    When DATENAME(wk,DateValue) = 26 And Year(DateValue) = 2012 Then 53

    When DATENAME(wk,DateValue) = 27 And Year(DateValue) = 2012 Then 1

    End As FiscalWeek -- this is only an example

    From mycte

    where DateValue between '2011-06-27' and '2012-07-01'

    OPTION (MAXRECURSION 0)

    What is the best way to get the FiscalWeek based on the results from above? I don't want to hard code every single Calendar week to get the corresponding Fiscal Week. Financial Year starts on 01/July

  • For this type of scenario, I would look at maybe implementing a calendar/tally table that holds all the necessary information against each day.

    My own calendar table stores (for each date) day number in year, fiscal month, fiscal year and other information relevant to the business. It's then just a simple case of linking the date in your transaction table to the calendar table to retrieve the columns required.

    We've expanded the calendar table recently to include such delights as: is a working day,is a national holiday, time sheet start day etc.

    There's lots of scripts around to generate these tables. SQLServerCentral.com and Google is your friend!

    :exclamation: "Be brave. Take risks. Nothing can substitute experience." :exclamation:

  • Well theres a possible typo in your code for the DATEMNAME(wk,DateValue)=29 which is repeated twice.

    I dont know if this is by design or not, but it seems odd that you classify week 29 as Week 3 and week 30 as week 5.

    A Simpler solution would be to use this case statement

    ,CASE WHEN DATENAME(wk,DateValue)>=27 then DATENAME(wk,DateValue)-26

    ELSE DATENAME(wk,DateValue)+27

    end

    It doesnt take into account any special logic like the WK 29 issue, and assumes every year follows the same pattern.

    It also makes the script easier to understand and maintain.

    As Robin suggested I would materialise this as a Calendar Table.

    _________________________________________________________________________
    SSC Guide to Posting and Best Practices

Viewing 3 posts - 1 through 2 (of 2 total)

You must be logged in to reply to this topic. Login to reply