Skip to content

Instantly share code, notes, and snippets.

@josheinstein
Last active August 29, 2015 13:58
Show Gist options
  • Save josheinstein/9935894 to your computer and use it in GitHub Desktop.
Save josheinstein/9935894 to your computer and use it in GitHub Desktop.
It isn't pretty, but it's ridiculously useful when you need to set a default value for a parameter in Microsoft SQL Server Report Builder. Simply use this view as the source of the default values and choose the column corresponding to the relative date you want to make the default.
CREATE VIEW ParameterDefaults_Date
AS
SELECT
CONVERT(date, GETUTCDATE()) AS [Today],
CONVERT(date, DATEADD(day, 1, GETUTCDATE())) AS [Tomorrow],
CONVERT(date, DATEADD(day, -1, GETUTCDATE())) AS [Yesterday],
CONVERT(date, DATEADD(day, 1-DATEPART(day, GETUTCDATE()), GETUTCDATE())) AS [ThisMonthStart],
CONVERT(date, DATEADD(day, -1, DATEADD(month, 1, DATEADD(day, 1-DATEPART(day, GETUTCDATE()), GETUTCDATE())))) AS [ThisMonthEnd],
CONVERT(date, DATEADD(month, 1, DATEADD(day, 1-DATEPART(day, GETUTCDATE()), GETUTCDATE()))) AS [NextMonthStart],
CONVERT(date, DATEADD(day, -1, DATEADD(month, 2, DATEADD(day, 1-DATEPART(day, GETUTCDATE()), GETUTCDATE())))) AS [NextMonthEnd],
CONVERT(date, DATEADD(month, -1, DATEADD(day, 1-DATEPART(day, GETUTCDATE()), GETUTCDATE()))) AS [LastMonthStart],
CONVERT(date, DATEADD(day, -1, DATEADD(day, 1-DATEPART(day, GETUTCDATE()), GETUTCDATE()))) AS [LastMonthEnd],
CONVERT(date, DATEADD(day, 1-DATEPART(weekday, GETUTCDATE()), GETUTCDATE())) AS [ThisWeekStart],
CONVERT(date, DATEADD(day, 6, DATEADD(day, 1-DATEPART(weekday, GETUTCDATE()), GETUTCDATE()))) AS [ThisWeekEnd],
CONVERT(date, DATEADD(week, 1, DATEADD(day, 1-DATEPART(weekday, GETUTCDATE()), GETUTCDATE()))) AS [NextWeekStart],
CONVERT(date, DATEADD(week, 1, DATEADD(day, 6, DATEADD(day, 1-DATEPART(weekday, GETUTCDATE()), GETUTCDATE())))) AS [NextWeekEnd],
CONVERT(date, DATEADD(week, -1, DATEADD(day, 1-DATEPART(weekday, GETUTCDATE()), GETUTCDATE()))) AS [LastWeekStart],
CONVERT(date, DATEADD(week, -1, DATEADD(day, 6, DATEADD(day, 1-DATEPART(weekday, GETUTCDATE()), GETUTCDATE())))) AS [LastWeekEnd]
-- Returns:
-- Today 4/2/2014
-- Tomorrow 4/3/2014
-- Yesterday 4/1/2014
-- ThisMonthStart 4/1/2014
-- ThisMonthEnd 4/30/2014
-- NextMonthStart 5/1/2014
-- NextMonthEnd 5/31/2014
-- LastMonthStart 3/1/2014
-- LastMonthEnd 3/31/2014
-- ThisWeekStart 3/30/2014
-- ThisWeekEnd 4/5/2014
-- NextWeekStart 4/6/2014
-- NextWeekEnd 4/12/2014
-- LastWeekStart 3/23/2014
-- LastWeekEnd 3/29/2014
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment