February 27, 2013 at 1:06 pm
Hi, I need help again.
I have a table with five approval dates. The columns could have a value but some could only have one, two or three. Out of all the columns, I need to get the last approval date.
For example, in my sample data, I need to retrieve timestamp4 in row 1, timestamp3 in row 2 and 3, and timestamp2 in row 4.
DDL and sample data.
CREATE TABLE [Dates](
ID [int] NULL,
PO [varchar](50) NULL,
timestamp1 [datetime] NULL,
timestamp2 [datetime] NULL,
timestamp3 [datetime] NULL,
timestamp4 [datetime] NULL
)
Insert into [Dates]
([ID], [PO], timestamp1, timestamp2, timestamp3, timestamp4)
SELECT 1, '12345', 'Jul 3 2012 4:48PM', 'Jul 3 2012 4:48PM', 'Jul 3 2012 4:48PM', 'Jul 3 2012 4:48PM' UNION ALL
SELECT 1, '12345', 'Jul 3 2012 4:48PM', 'Jul 3 2012 4:48PM', 'Jul 3 2012 4:48PM', null UNION ALL
SELECT 1, '12345', 'Jul 3 2012 4:48PM', 'Jul 3 2012 4:48PM', 'Jul 3 2012 4:48PM', null UNION ALL
SELECT 1, '12345', 'Jul 3 2012 4:48PM', 'Jul 3 2012 4:48PM', null, null
Thanks.
February 27, 2013 at 1:19 pm
great job on giving us the setup DDL and Data.
Your data has all the same datetimes, so it'll probably look better when you compare the example with real data.
this seems to work for me, is this what you are after?
SELECT
ID,
PO,
CASE WHEN ISNULL(timestamp1,'1900-01-01') >= ISNULL(timestamp2,'1900-01-01')
AND ISNULL(timestamp1,'1900-01-01') >= ISNULL(timestamp3,'1900-01-01')
AND ISNULL(timestamp1,'1900-01-01') >= ISNULL(timestamp4,'1900-01-01')
THEN ISNULL(timestamp1,'1900-01-01')
WHEN ISNULL(timestamp2,'1900-01-01') >= ISNULL(timestamp1,'1900-01-01')
AND ISNULL(timestamp2,'1900-01-01') >= ISNULL(timestamp3,'1900-01-01')
AND ISNULL(timestamp2,'1900-01-01') >= ISNULL(timestamp4,'1900-01-01')
THEN ISNULL(timestamp2,'1900-01-01')
WHEN ISNULL(timestamp3,'1900-01-01') >= ISNULL(timestamp1,'1900-01-01')
AND ISNULL(timestamp3,'1900-01-01') >= ISNULL(timestamp2,'1900-01-01')
AND ISNULL(timestamp3,'1900-01-01') >= ISNULL(timestamp4,'1900-01-01')
THEN ISNULL(timestamp3,'1900-01-01')
WHEN ISNULL(timestamp4,'1900-01-01') >= ISNULL(timestamp1,'1900-01-01')
AND ISNULL(timestamp4,'1900-01-01') >= ISNULL(timestamp2,'1900-01-01')
AND ISNULL(timestamp4,'1900-01-01') >= ISNULL(timestamp3,'1900-01-01')
THEN ISNULL(timestamp4,'1900-01-01')
END As MaxDate
FROM [Dates]
Lowell
February 27, 2013 at 1:23 pm
or did you mean the last non-null column, regardless of the datetime value? my example above finds the highest date, regardless of which column.
in that case, assuming your app files the columns up in left to right order(timestamp1,imestamp2,imestamp3,imestamp4) it would be like this:
SELECT
ID,
PO,
COALESCE(timestamp4,timestamp3,timestamp2,timestamp1) AS MaxDate
FROM [Dates]
Lowell
February 27, 2013 at 1:41 pm
I need to get the last value regardless of the actual date.
I tried both solutions and both work.
Thank you.
February 27, 2013 at 10:19 pm
josetur12 (2/27/2013)
I need to get the last value regardless of the actual date.I tried both solutions and both work.
Thank you.
You might also want to consider changing the structure of the table. The way it is, it'll be interesting when they come up with a 5th date.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply