The first day of the week
Under some assumptions the task can be solved as follows:
WITH num(n) AS(/* With aid of [recursive CTE](/ru/book_recursive_cte.html "Общие табличные выражения") get a table having single column n
with sequence of integer values from 0 to 6 */
SELECT 0
UNION ALL
SELECT n+1 FROM num
WHERE n < 6),
dat AS (/* Getting table with dates from January 1 to 7, 2013 */
SELECT DATEADD(dd, n, CAST('2013-01-01' AS DATETIME)) AS day FROM num
)
SELECT day FROM dat WHERE DATEPART(dw, day) = 1; /* Taking the day that corresponds
to the first day of a week */
[[ column ]] |
---|
NULL [[ value ]] |
The assumption we mentioned above adopts Monday as the first day of a week. However, running of the query on the sql-ex.ru site gives us
day |
---|
2013-01-06 |
WITH num(n) AS (SELECT 0
UNION ALL
SELECT n+1 FROM num
WHERE n < 6),
dat AS (
SELECT DATEADD(dd, n, CAST('2013-01-01' AS DATETIME)) AS day FROM num
)
SELECT day FROM dat WHERE DATENAME(dw, day) = 'monday';
[[ column ]] |
---|
NULL [[ value ]] |
day |
---|
2013-01-07 |
This is true now, but will this query be true always if we shall embed it into application code? The answer is no. If language settings will be changed
SET
LANGUAGE german;
we’ll get empty row set because the last line in the query should be written as
SELECT day FROM dat WHERE DATENAME(dw, day) ='Montag';
@@DATEFIRST function
@@DATEFIRST returns an integer which defines the first day of a week for the current session. In so doing, 1 is corresponding to Monday, but 7 - to Sunday respectively. I.e. if
SELECT
@@DATEFIRST;
[[ column ]] |
---|
NULL [[ value ]] |
To make our solution to the task be independent on the first-day-of-week settings, we need to use @@DATEFIRST function, for example
WITH num(n) AS(
SELECT 0
UNION ALL
SELECT n+1 FROM num
WHERE n < 6),
dat AS (
SELECT DATEADD(dd, n, CAST('2013-01-01' AS DATETIME)) AS day FROM num
)
SELECT day, DATENAME(dw, day) week_day FROM dat WHERE DATEPART(dw, day) =
1+(8-@@DATEFIRST) % 7;
[[ column ]] |
---|
NULL [[ value ]] |
day | week_day |
---|---|
2013-01-07 | Monday |
To change value of the first day of a week (for a current session), we can use SET DATEFIRST statement. So, if we run the following script
SET DATEFIRST 1;
SELECT @@DATEFIRST;
we’ll obtain 1, i.e. week starts with Monday now.
The first-day-of-a-week settings may be changed through the changing of session language. For example, running
SET LANGUAGE us_english;
SELECT
@@DATEFIRST;
lead us to 7 (Sunday) once more, as this value is default for U.S. English, whereas choosing German will do Monday to be the first day of a week.
Nevertheless you can change the language parameter and first day of a week simultaneously to obtain, say, English and a week that will start with Monday:
SET DATEFIRST 1;
SET LANGUAGE us_english;
SELECT @@DATEFIRST;
Language settings impact specifically on the string representation of date/time components. Compare these results:
DECLARE @dt DATE = '2012-12-17'; -- December 17, 2012
SET LANGUAGE us_english;
SELECT DATENAME(DW, @dt) AS day_of_week, DATENAME(MONTH,@dt) AS month;
day_of_week | month |
---|---|
Monday | December |
SET LANGUAGE german;
SELECT DATENAME(DW, @dt) AS day_of_week, DATENAME(MONTH, @dt) AS month;
day_of_week | month |
---|---|
Montag | Dezember |
Conclusion. If you want to have queries that always give correct results for any settings of server or database, you can specify necessary setting parameters for the session in which these queries are executing; or you need to check the values of corresponding parameters (@@DATEFIRST as example) in each such a query.
Peculiarities: MSSQL (V.I.Gershovich)
You can solve this problem (First occurrence of a Monday in January 2013) without use of @@DATEFIRST with aid of method proposed by Itzik Ben-Gan [8]. The idea of the solution is based on the following:
- January 1, 1900 was a Monday
- The number of days between two similar days of the week is divisible by seven
declare @anchor_date datetime
declare @reference_date datetime
select @anchor_date='19000101', @reference_date='20130505'
SELECT DATEADD(day, DATEDIFF(day, @anchor_date,
DATEADD(year, DATEDIFF(year, '19000101', @reference_date), '19000101') - 1) /7*7 + 7,
@anchor_date);
Peculiarities: MSSQL (P.A.Kurochkin)
It is possible to mention one more way to solve this task without use of @@DATEFIRST. The method is based on comparison of any function DATEPART/DATENAME with the same function taking the date being Monday as parameter. For example, it may be January 1st, 1900 (already mentioned).
Then the initial query in this chapter would look like as
SELECT day FROM dat WHERE DATEPART(dw, day) = DATEPART(dw, '19000101');
or as
SELECT day FROM dat WHERE DATENAME(dw, day) = DATENAME(dw, '19000101');