SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Last friday's date that is in a table


Last friday's date that is in a table

Author
Message
mick burden
mick burden
Hall of Fame
Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)

Group: General Forum Members
Points: 3631 Visits: 486
I've googled the hell out of this question with no luck, I've seen countless snippets to get the date of the last Friday using todays date or
passing in a date, what I'm actually after is to work on a table and get the last Friday's date that appears in the table, I say Friday's date it would be great to be able to pass in any day of the week. I've made a dummy table to try this out and my script is below, I'd appreciate any help on this.


USE test
GO
-- Creating Test Table
CREATE TABLE testtable(date datetime, Job VARCHAR(20))
GO
-- Inserting Data into Table
INSERT INTO testtable(date,job)
VALUES('01/Jan/2018','Test1')
INSERT INTO testtable(date,job)
VALUES('09/Dec/2017','Test2')
INSERT INTO testtable(date,job)
VALUES('08/Dec/2017','Test3')
INSERT INTO testtable(date,job)
VALUES('01/Nov/2017','Test4')
INSERT INTO testtable(date,job)
VALUES('01/Dec/2011','Test5')



This should return 8-12-2017, 'Test3'
the date format is irrelevant as I can sort that out when it's returned.

Many thanks
Mick


Neil Burton
Neil Burton
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18903 Visits: 12292
mick burden - Friday, January 19, 2018 6:31 AM
I've googled the hell out of this question with no luck, I've seen countless snippets to get the date of the last Friday using todays date or
passing in a date, what I'm actually after is to work on a table and get the last Friday's date that appears in the table, I say Friday's date it would be great to be able to pass in any day of the week. I've made a dummy table to try this out and my script is below, I'd appreciate any help on this.


USE test
GO
-- Creating Test Table
CREATE TABLE testtable(date datetime, Job VARCHAR(20))
GO
-- Inserting Data into Table
INSERT INTO testtable(date,job)
VALUES('01/Jan/2018','Test1')
INSERT INTO testtable(date,job)
VALUES('09/Dec/2017','Test2')
INSERT INTO testtable(date,job)
VALUES('08/Dec/2017','Test3')
INSERT INTO testtable(date,job)
VALUES('01/Nov/2017','Test4')
INSERT INTO testtable(date,job)
VALUES('01/Dec/2011','Test5')



This should return 8-12-2017, 'Test3'
the date format is irrelevant as I can sort that out when it's returned.

Many thanks
Mick



CREATE TABLE #testtable(date datetime, Job VARCHAR(20))
GO
-- Inserting Data into Table
INSERT INTO #testtable(date,job)
VALUES
('01/Jan/2018','Test1')
,('09/Dec/2017','Test2')
,('08/Dec/2017','Test3')
,('01/Nov/2017','Test4')
,('01/Dec/2011','Test5')

DECLARE @Weekday CHAR(9) = 'Friday'

SELECT
date
,job
FROM
#testtable t
JOIN (
SELECT
MAX(DATE) AS last_day
FROM #testtable
CROSS JOIN
(VALUES('Sunday',1)
,('Monday',2)
,('Tuesday',3)
,('Wednesday',4)
,('Thursday',5)
,('Friday',6)
,('Saturday',7)
)d(DoW,dw)
WHERE
datepart(dw,date) = d.dw
AND d.DoW = @Weekday
) ld ON ld.last_day = t.date
DROP TABLE
#testtable


This will do what you want and can be used with any day of the week. Let me know if you've got any questions.



On two occasions I have been asked, "Pray, Mr. Babbage, if you put into the machine wrong figures, will the right answers come out?" ... I am not able rightly to apprehend the kind of confusion of ideas that could provoke such a question.
—Charles Babbage, Passages from the Life of a Philosopher

How to post a question to get the most help
mick burden
mick burden
Hall of Fame
Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)

Group: General Forum Members
Points: 3631 Visits: 486
Neil Burton - Friday, January 19, 2018 7:24 AM
mick burden - Friday, January 19, 2018 6:31 AM
I've googled the hell out of this question with no luck, I've seen countless snippets to get the date of the last Friday using todays date or
passing in a date, what I'm actually after is to work on a table and get the last Friday's date that appears in the table, I say Friday's date it would be great to be able to pass in any day of the week. I've made a dummy table to try this out and my script is below, I'd appreciate any help on this.


USE test
GO
-- Creating Test Table
CREATE TABLE testtable(date datetime, Job VARCHAR(20))
GO
-- Inserting Data into Table
INSERT INTO testtable(date,job)
VALUES('01/Jan/2018','Test1')
INSERT INTO testtable(date,job)
VALUES('09/Dec/2017','Test2')
INSERT INTO testtable(date,job)
VALUES('08/Dec/2017','Test3')
INSERT INTO testtable(date,job)
VALUES('01/Nov/2017','Test4')
INSERT INTO testtable(date,job)
VALUES('01/Dec/2011','Test5')



This should return 8-12-2017, 'Test3'
the date format is irrelevant as I can sort that out when it's returned.

Many thanks
Mick



CREATE TABLE #testtable(date datetime, Job VARCHAR(20))
GO
-- Inserting Data into Table
INSERT INTO #testtable(date,job)
VALUES('01/Jan/2018','Test1')
INSERT INTO #testtable(date,job)
VALUES('09/Dec/2017','Test2')
INSERT INTO #testtable(date,job)
VALUES('08/Dec/2017','Test3')
INSERT INTO #testtable(date,job)
VALUES('01/Nov/2017','Test4')
INSERT INTO #testtable(date,job)
VALUES('01/Dec/2011','Test5')

DECLARE @Weekday CHAR(9) = 'Friday'

SELECT
date
,job
FROM
#testtable t
JOIN (
SELECT
MAX(DATE) AS last_day
FROM #testtable
CROSS JOIN
(VALUES('Sunday',1)
,('Monday',2)
,('Tuesday',3)
,('Wednesday',4)
,('Thursday',5)
,('Friday',6)
,('Saturday',7)
)d(DoW,dw)
WHERE
datepart(dw,date) = d.dw
AND d.DoW = @Weekday
) ld ON ld.last_day = t.date
DROP TABLE
#testtable


This will do what you want and can be used with any day of the week. Let me know if you've got any questions.


That's fantastic Neil, exactly what I needed
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum








































































































































































SQLServerCentral


Search