Author |
Topic |
SwePeso
Patron Saint of Lost Yaks
30421 Posts |
Posted - 2007-07-23 : 20:44:25
|
Riding MVJ's excellent F_TABLE_DATE function, I often use this view for current date and time information.SELECT CURRENT_TIMESTAMP AS Now, DATEADD(MINUTE, DATEDIFF(MINUTE, 0.00069445, CURRENT_TIMESTAMP), 0) AS previousMinute, DATEADD(MINUTE, DATEDIFF(MINUTE, 0, CURRENT_TIMESTAMP), 0) AS thisMinute, DATEADD(MINUTE, DATEDIFF(MINUTE, 0, CURRENT_TIMESTAMP), 0.00069445) AS nextMinute, DATEADD(HOUR, DATEDIFF(HOUR, 0.0416667, CURRENT_TIMESTAMP), 0) AS previousHour, DATEADD(HOUR, DATEDIFF(HOUR, 0, CURRENT_TIMESTAMP), 0) AS thisHour, DATEADD(HOUR, DATEDIFF(HOUR, 0, CURRENT_TIMESTAMP), 0.0416667) AS nextHour, DATEADD(DAY, DATEDIFF(DAY, 1, CURRENT_TIMESTAMP), 0) AS previousDay, DATEADD(DAY, DATEDIFF(DAY, 0, CURRENT_TIMESTAMP), 0) AS thisDay, DATEADD(DAY, DATEDIFF(DAY, 0, CURRENT_TIMESTAMP), 1) AS nextDay, DATEADD(WEEK, DATEDIFF(WEEK, 7, CURRENT_TIMESTAMP), 0) AS previousWeek, DATEADD(WEEK, DATEDIFF(WEEK, 0, CURRENT_TIMESTAMP), 0) AS thisWeek, DATEADD(WEEK, DATEDIFF(WEEK, 0, CURRENT_TIMESTAMP), 7) AS nextWeek, DATEADD(MONTH, DATEDIFF(MONTH, 31, CURRENT_TIMESTAMP), 0) AS previousMonth, DATEADD(MONTH, DATEDIFF(MONTH, 0, CURRENT_TIMESTAMP), 0) AS thisMonth, DATEADD(MONTH, DATEDIFF(MONTH, -1, CURRENT_TIMESTAMP), 0) AS nextMonth, DATEADD(QUARTER, DATEDIFF(QUARTER, 92, CURRENT_TIMESTAMP), 0) AS previousQuarter, DATEADD(QUARTER, DATEDIFF(QUARTER, 0, CURRENT_TIMESTAMP), 0) AS thisQuarter, DATEADD(QUARTER, DATEDIFF(QUARTER, -1, CURRENT_TIMESTAMP), 0) AS nextQuarter, DATEADD(YEAR, DATEDIFF(YEAR, 365, CURRENT_TIMESTAMP), 0) AS previousYear, DATEADD(YEAR, DATEDIFF(YEAR, 0, CURRENT_TIMESTAMP), 0) AS thisYear, DATEADD(YEAR, DATEDIFF(YEAR, -1, CURRENT_TIMESTAMP), 0) AS nextYear For example, If I want this weeks data I just join against this view and useWHERE DtCol >= thisWeek AND DtCol < nextWeek Or previous months dataWHERE DtCol >= previousMonth AND DtCol < thisMonth EDIT: Faster week calculations. |
|
khtan
In (Som, Ni, Yak)
17689 Posts |
Posted - 2007-07-23 : 22:04:36
|
Sorry, but i don't see any references to the F_TABLE_DATE used in your view here. KH[spoiler]Time is always against us[/spoiler] |
|
|
SwePeso
Patron Saint of Lost Yaks
30421 Posts |
Posted - 2007-07-24 : 02:23:11
|
The text "here" is a link to Michaels function.Peter LarssonHelsingborg, Sweden |
|
|
khtan
In (Som, Ni, Yak)
17689 Posts |
Posted - 2007-07-24 : 03:00:55
|
Oh, i see KH[spoiler]Time is always against us[/spoiler] |
|
|
SwePeso
Patron Saint of Lost Yaks
30421 Posts |
Posted - 2007-07-24 : 03:06:26
|
I will edit the original post to avoid the confusion in the future.Peter LarssonHelsingborg, Sweden |
|
|
SwePeso
Patron Saint of Lost Yaks
30421 Posts |
Posted - 2007-10-18 : 07:07:21
|
[code]SELECT CURRENT_TIMESTAMP AS Now, DATEADD(DAY, DATEDIFF(DAY, CURRENT_TIMESTAMP, '19000101'), CURRENT_TIMESTAMP) AS theTimeOnly, DATEADD(MINUTE, DATEDIFF(MINUTE, '00:01:00', CURRENT_TIMESTAMP), '19000101') AS previousMinute, DATEADD(MINUTE, DATEDIFF(MINUTE, '19000101', CURRENT_TIMESTAMP), '19000101') AS thisMinute, DATEADD(MINUTE, DATEDIFF(MINUTE, '19000101', CURRENT_TIMESTAMP), '00:01:00') AS nextMinute, DATEADD(HOUR, DATEDIFF(HOUR, '01:00:00', CURRENT_TIMESTAMP), '19000101') AS previousHour, DATEADD(HOUR, DATEDIFF(HOUR, '19000101', CURRENT_TIMESTAMP), '19000101') AS thisHour, DATEADD(HOUR, DATEDIFF(HOUR, '19000101', CURRENT_TIMESTAMP), '01:00:00') AS nextHour, DATEADD(DAY, DATEDIFF(DAY, '19000102', CURRENT_TIMESTAMP), '19000101') AS previousDay, DATEADD(DAY, DATEDIFF(DAY, '19000101', CURRENT_TIMESTAMP), '19000101') AS thisDay, DATEADD(DAY, DATEDIFF(DAY, '19000101', CURRENT_TIMESTAMP), '19000102') AS nextDay, DATEADD(WEEK, DATEDIFF(WEEK, '19000108', CURRENT_TIMESTAMP), '19000101') AS previousWeek, DATEADD(WEEK, DATEDIFF(WEEK, '19000101', CURRENT_TIMESTAMP), '19000101') AS thisWeek, DATEADD(WEEK, DATEDIFF(WEEK, '19000101', CURRENT_TIMESTAMP), '19000108') AS nextWeek, DATEADD(MONTH, DATEDIFF(MONTH, '19000201', CURRENT_TIMESTAMP), '19000101') AS previousMonth, DATEADD(MONTH, DATEDIFF(MONTH, '19000101', CURRENT_TIMESTAMP), '19000101') AS thisMonth, DATEADD(MONTH, DATEDIFF(MONTH, '18991231', CURRENT_TIMESTAMP), '19000101') AS nextMonth, DATEADD(QUARTER, DATEDIFF(QUARTER, '19000401', CURRENT_TIMESTAMP), '19000101') AS previousQuarter, DATEADD(QUARTER, DATEDIFF(QUARTER, '19000101', CURRENT_TIMESTAMP), '19000101') AS thisQuarter, DATEADD(QUARTER, DATEDIFF(QUARTER, '18991231', CURRENT_TIMESTAMP), '19000101') AS nextQuarter, DATEADD(YEAR, DATEDIFF(YEAR, '19010101', CURRENT_TIMESTAMP), '19000101') AS previousYear, DATEADD(YEAR, DATEDIFF(YEAR, '19000101', CURRENT_TIMESTAMP), '19000101') AS thisYear, DATEADD(YEAR, DATEDIFF(YEAR, '18991231', CURRENT_TIMESTAMP), '19000101') AS nextYear[/code] E 12°55'05.25"N 56°04'39.16" |
|
|
|
|
|