Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Selecting the Row with the MAX(DateStarted)


Selecting the Row with the MAX(DateStarted)

Author
Message
AndrewSQLDBA
AndrewSQLDBA
Ten Centuries
Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)

Group: General Forum Members
Points: 1008 Visits: 3427
Hello Everyone
I am working on a query that needs to select the MAX(DateStated). There are other rows with the same ProductID and Different RowID. I am trying to select the Only row if there is only one ProductID, and if there are Multiple of the same ProductID, then select the one with the MAX(DateStarted)

I have used Row_Number(), but I was asked to not use that for this query. Kind of makes things rather difficult. This query will not only need to be ran against a SQL Server database, but possible a (And I hate saying this) DB2 database.Crying

I greatly appreciate any and all assistance. Thank You in advance for all your suggestions, assistance and comments

Andrew SQLDBA


CREATE TABLE #AllData
(
   DateStarted Datetime
,   RowID int
,   ProductID bigint
)

INSERT INTO #AllData

SELECT '2012-06-01 06:03:46.023',   66937,   777002387 UNION ALL
SELECT '2012-06-01 14:03:57.780',   67100,   777002387 UNION ALL
SELECT '2012-06-02 06:03:44.377',   67243,   777002387 UNION ALL
SELECT '2012-06-02 14:03:43.873',   67347,   777002387 UNION ALL
SELECT '2012-09-24 21:09:16.183',   75558,   701327244 UNION ALL
SELECT '2012-06-30 06:02:40.850',   75357,   701298894 UNION ALL
SELECT '2012-06-30 14:02:42.547',   75461,   701298894 UNION ALL
SELECT '2012-06-30 06:02:56.210',   75369,   701298827 UNION ALL
SELECT '2012-06-30 14:03:00.770',   75473,   701298827 UNION ALL
SELECT '2012-06-29 06:02:39.467',   75157,   701298589 UNION ALL
SELECT '2012-06-29 14:02:37.700',   75260,   701298589 UNION ALL
SELECT '2012-06-30 06:03:11.013',   75381,   701298589 UNION ALL
SELECT '2012-06-30 14:03:14.190',   75484,   701298589 UNION ALL
SELECT '2012-06-29 06:02:41.137',   75158,   701298587 UNION ALL
SELECT '2012-06-29 14:02:39.553',   75261,   701298587 UNION ALL
SELECT '2012-06-30 06:03:12.400',   75382,   701298587 UNION ALL
SELECT '2012-06-30 14:03:15.590',   75485,   701298587 UNION ALL
SELECT '2012-06-28 14:02:35.307',   75052,   701298403 UNION ALL
SELECT '2012-06-29 06:03:05.407',   75173,   701298373 UNION ALL
SELECT '2012-06-29 14:03:01.060',   75275,   701298373 UNION ALL
SELECT '2012-06-30 06:03:23.780',   75394,   701298373 UNION ALL
SELECT '2012-06-30 14:03:25.600',   75496,   701298373 UNION ALL
SELECT '2012-06-28 06:02:45.220',   74955,   701298288 UNION ALL
SELECT '2012-06-28 14:02:47.733',   75059,   701298288 UNION ALL
SELECT '2012-06-28 06:03:02.437',   74966,   701298112 UNION ALL
SELECT '2012-06-28 14:03:06.297',   75070,   701298112 UNION ALL
SELECT '2012-06-29 06:03:15.763',   75185,   701298112 UNION ALL
SELECT '2012-06-29 14:03:09.863',   75286,   701298112 UNION ALL
SELECT '2012-06-27 06:02:36.813',   74753,   701297947 UNION ALL
SELECT '2012-06-27 14:02:42.880',   74856,   701297947 UNION ALL
SELECT '2012-06-28 06:03:19.753',   74977,   701297947 UNION ALL
SELECT '2012-06-28 14:03:21.300',   75081,   701297947 UNION ALL
SELECT '2012-06-29 06:03:22.450',   75194,   701297947 UNION ALL
SELECT '2012-06-29 14:03:15.533',   75295,   701297947 UNION ALL
SELECT '2012-06-26 14:02:33.670',   74652,   701297565 UNION ALL
SELECT '2012-06-27 06:03:01.627',   74768,   701297565 UNION ALL
SELECT '2012-06-27 14:03:08.833',   74871,   701297565

SELECT * FROM #AllData
ORDER BY ProductID DESC

DROP TABLE #AllData



ResultSet:


DateStarted         RowID   ProductID
2012-06-01 06:03:46.023   66937   777002387
2012-06-01 14:03:57.780   67100   777002387
2012-06-02 06:03:44.377   67243   777002387
2012-06-02 14:03:43.873   67347   777002387 <-- Need This one
2012-09-24 21:09:16.183   75558   701327244 <-- Need This one
2012-06-30 06:02:40.850   75357   701298894
2012-06-30 14:02:42.547   75461   701298894 <-- Need This one
2012-06-30 06:02:56.210   75369   701298827
2012-06-30 14:03:00.770   75473   701298827 <-- Need This one
2012-06-29 06:02:39.467   75157   701298589
2012-06-29 14:02:37.700   75260   701298589
2012-06-30 06:03:11.013   75381   701298589
2012-06-30 14:03:14.190   75484   701298589 <-- Need This one
2012-06-29 06:02:41.137   75158   701298587
2012-06-29 14:02:39.553   75261   701298587
2012-06-30 06:03:12.400   75382   701298587
2012-06-30 14:03:15.590   75485   701298587 <-- Need This one
2012-06-28 14:02:35.307   75052   701298403
2012-06-29 06:03:05.407   75173   701298373
2012-06-29 14:03:01.060   75275   701298373
2012-06-30 06:03:23.780   75394   701298373
2012-06-30 14:03:25.600   75496   701298373 <-- Need This one
2012-06-28 06:02:45.220   74955   701298288
2012-06-28 14:02:47.733   75059   701298288 <-- Need This one
2012-06-28 06:03:02.437   74966   701298112
2012-06-28 14:03:06.297   75070   701298112
2012-06-29 06:03:15.763   75185   701298112
2012-06-29 14:03:09.863   75286   701298112 <-- Need This one
2012-06-27 06:02:36.813   74753   701297947
2012-06-27 14:02:42.880   74856   701297947
2012-06-28 06:03:19.753   74977   701297947
2012-06-28 14:03:21.300   75081   701297947
2012-06-29 06:03:22.450   75194   701297947
2012-06-29 14:03:15.533   75295   701297947 <-- Need This one
2012-06-26 14:02:33.670   74652   701297565
2012-06-27 06:03:01.627   74768   701297565
2012-06-27 14:03:08.833   74871   701297565 <-- Need This one



dwain.c
dwain.c
SSCarpal Tunnel
SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)

Group: General Forum Members
Points: 4241 Visits: 6431
As long as you don't have any duplicates in the MAX date, you can do it this way:


WITH GroupedData AS
(
SELECT DateStarted=MAX(DateStarted), ProductID
FROM #AllData
GROUP BY ProductID
)
SELECT a.*
FROM #AllData a
JOIN GroupedData b
ON a.ProductID = b.ProductID AND a.DateStarted = b.DateStarted
ORDER BY a.ProductID DESC;





My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
parulprabu
parulprabu
UDP Broadcaster
UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)

Group: General Forum Members
Points: 1454 Visits: 136
dwain.c (10/16/2013)
As long as you don't have any duplicates in the MAX date:




SELECT * FROM #AllData WHERE CONVERT(VARCHAR(20),DateStarted) + CONVERT(VARCHAR(30), ProductID) IN(
SELECT CONVERT(VARCHAR(20),max(DateStarted))+ CONVERT(VARCHAR(30), ProductID) FROM #AllData
group BY ProductID)


AndrewSQLDBA
AndrewSQLDBA
Ten Centuries
Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)

Group: General Forum Members
Points: 1008 Visits: 3427
Thanks DWain
That is exactly what I was after. Works very fast also. Got to Love that part.

Andrew SQLDBA
dwain.c
dwain.c
SSCarpal Tunnel
SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)

Group: General Forum Members
Points: 4241 Visits: 6431
You're most welcome.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
Cadavre
Cadavre
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2594 Visits: 8436
Don't know if it's any better, but an alternative is: -

SELECT DateStarted, RowID, ProductID
FROM (SELECT DateStarted, RowID, ProductID,
MAX(DateStarted) OVER(PARTITION BY ProductID) AS MaxDateStarted
FROM #AllData
) a
WHERE a.DateStarted = a.MaxDateStarted
ORDER BY a.ProductID DESC;




Forever trying to learn

For better, quicker answers on T-SQL questions, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better, quicker answers on SQL Server performance related questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/



If you litter your database queries with nolock query hints, are you aware of the side effects?
Try reading a few of these links...

(*) Missing rows with nolock
(*) Allocation order scans with nolock
(*) Consistency issues with nolock
(*) Transient Corruption Errors in SQL Server error log caused by nolock
(*) Dirty reads, read errors, reading rows twice and missing rows with nolock


Craig Wilkinson - Software Engineer
LinkedIn
AndrewSQLDBA
AndrewSQLDBA
Ten Centuries
Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)

Group: General Forum Members
Points: 1008 Visits: 3427
Thanks Cadavre
That one works really efficiently also. I will keep that code handy.

Greatly appreciate it

Andrew SQLDBA
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