Thanks Chris,
This looks like exactly what I need. Not sure I totally understand the Cross join, but I'm going to spend some time to understand.
Thanks
Mike
-----Original Message-----
From: MIDRANGE-L [mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Hiebert, Chris
Sent: Monday, March 20, 2017 7:53 PM
To: Midrange Systems Technical Discussion <midrange-l@xxxxxxxxxxxx>
Subject: RE: getting record with highest date/time
You need to create a list of your unique values.
Then using those as a base, you go back into the table to get the other data that you need.
Here is an example using "Cross Join Table(...)" which is equivalent to a "Join Lateral(...) on 1=1".
With t1 as (select HSTBATCH, hstmtr# FROM readingbatch group by HSTBATCH, hstmtr#) Select T1.HSTBATCH, T1.hstmtr#, T2.HSTREAD, T2.HSTRDATE, T2.HSTRTIME FROM T1 CROSS JOIN TABLE ( SELECT T2.HSTREAD, T2.HSTRDATE, T2.HSTRTIME FROM readingbatch T2 WHERE T2. HSTBATCH = T1.HSTBATCH AND T2.hstmtr# = T1. hstmtr# ORDER BY HSTRDATE desc, HSTRTIME desc Fetch first 1 rows only) t2
Chris Hiebert
Senior Programmer/Analyst
Disclaimer: Any views or opinions presented are solely those of the author and do not necessarily represent those of the company.
-----Original Message-----
From: MIDRANGE-L [mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Smith, Mike
Sent: Monday, March 20, 2017 3:23 PM
To: Midrange Systems Technical Discussion (midrange-l@xxxxxxxxxxxx) <midrange-l@xxxxxxxxxxxx>
Subject: getting record with highest date/time
I am working on a sql statement to get the record that has the highest date/time for a meter I'm close, but when I try to include my reading data, I don't get the results I want.
So my data looks something like this filename "ReadingBatch)
HSTBATCH HSTMTR# HSTREAD HSTRDATE HSTRTIME
IMR07 66016 9,734 20,170,216 100,000
IMR07 66016 9,737 20,170,217 100,000
IMR07 66016 9,738 20,170,218 100,000
IMR07 66016 9,739 20,170,219 100,000
IMR07 66016 9,741 20,170,220 100,000
IMR07 66016 9,743 20,170,221 100,000
IMR07 66016 9,744 20,170,222 100,000
IMR07 66016 9,746 20,170,223 100,000
IMR07 66016 9,746 20,170,224 100,000
IMR07 66016 9,747 20,170,225 100,000
IMR07 66016 9,749 20,170,226 100,000
IMR07 66016 9,752 20,170,227 100,000
IMR07 66016 9,755 20,170,228 100,000
IMR07 66016 9,756 20,170,301 100,000
IMR07 66016 9,758 20,170,302 111,825
IMR07 66016 9,758 20,170,302 100,000
IMR07 101644 8,612 20,170,301 100,000
IMR07 101644 8,613 20,170,302 112,426
IMR07 101644 8,613 20,170,302 100,000
This is my current sql statement which appears to pick up the correct data, just not the HSTREAD field
SELECT HSTBATCH, max(concat(concat(hstrdate, ' '),hstrtime)) as HT, HSTMTR# FROM readingbatch WHERE hstbatch = 'IMR07' GROUP BY hstbatch, hstmtr# ORDER BY hstmtr#
If I add the field HSTREAD I get too many records.
In this example what I want to end up with is
IMR07 66016 9758 20170302 111825
IMR07 101644 8613 20170302 112426
Any help is appreciated.
Mike
NOTICE: This message, including any attachment, is intended as a confidential and privileged communication. If you have received this message in error, or are not the named recipient(s), please immediately notify the sender and delete this message.
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list To post a message email: MIDRANGE-L@xxxxxxxxxxxx To subscribe, unsubscribe, or change list options,
visit:
http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx Before posting, please take a moment to review the archives at
http://archive.midrange.com/midrange-l.
Please contact support@xxxxxxxxxxxx for any subscription related questions.
Help support midrange.com by shopping at amazon.com with our affiliate link:
http://amzn.to/2dEadiD
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit:
http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives
at
http://archive.midrange.com/midrange-l.
Please contact support@xxxxxxxxxxxx for any subscription related questions.
Help support midrange.com by shopping at amazon.com with our affiliate link:
http://amzn.to/2dEadiD
NOTICE: This message, including any attachment, is intended as a confidential and privileged communication. If you have received this message in error, or are not the named recipient(s), please immediately notify the sender and delete this message.
As an Amazon Associate we earn from qualifying purchases.