|
Yeah that's much better. Timestamp ordering makes sense, but in his sample data they all have the exact same timestamp. So I'm not sure which record you would get first, it seems to me you could randomly get one of of the 5 rows in his sample data set, nothing is controlling the fact that he would get the first row in his dataset versus the last row. Granted if there were inserted in that order they might come out that way, but nothing is going to guarantee a data re-orgnization wouldn't totally hose his data up. Seems he is missing an identity column which would probably sort this mess out.
-----Original Message-----
From: Tom E Stieger [mailto:testieger@xxxxxxxxxxxx]
Sent: Wednesday, February 06, 2013 4:43 PM
To: Midrange Systems Technical Discussion
Subject: RE: sql - group by clause, aggregate returning first record values for rest of fields.
The problem with using the MIN() function is that you get data from multiple records that are evaluated for each min field desired. With the ROW_NUMBER() function we are starting a new row count over his desired group by fields (using the PARTION BY clause) and showing the other fields regardless as to whether they are the MIN() for that group. I had assumed that he had unique ordering by that PARTITION clause. Looking over his sample data he should probably amend it to:
ROW_NUMBER() OVER(PARTITION BY usrinusr, usrinjob, usrinnbr ORDER BY usrintstmp)
This will guarantee the first timestamp record is retrieved.
-Tom Stieger
IT Manager
California Fine Wire
-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx [mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Matt Olson
Sent: Wednesday, February 06, 2013 2:18 PM
To: Midrange Systems Technical Discussion
Subject: RE: sql - group by clause, aggregate returning first record values for rest of fields.
I don't believe this will yield your desired results every time however, you could randomly get the same results that the MIN() query provided to you depending on the rows the query engine wanted to return to you first.
Atleast with the MIN query you would know what row you are going to get (minimum of all the result of the column values) instead of random record the query engine decided to retrieve first.
-----Original Message-----
From: Gqcy [mailto:gmufasa01@xxxxxxxxx]
Sent: Wednesday, February 06, 2013 3:57 PM
To: midrange-l@xxxxxxxxxxxx
Subject: Re: sql - group by clause, aggregate returning first record values for rest of fields.
Thanks Tom,
this worked perfectly.
Except we should use "parTITion" not "partion"..
:)
On 2/6/2013 3:42 PM, Tom E Stieger wrote:
Try the following:
With sorted as (select usrinusr, usrinjob, usrinnbr, usrinlvl,
usrinpgm, usrintstmp,
Row_number() over(partion by usrinusr, usrinjob, usrinnbr) as rowno
from mgpll/usrinpf1 ) select usrinusr, usrinjob, usrinnbr, usrinlvl,
usrinpgm, usrintstmp from sorted where rowno = 1
-Tom Stieger
IT Manager
California Fine Wire
-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx
[mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Gqcy
Sent: Wednesday, February 06, 2013 12:43 PM
To: midrange-l@xxxxxxxxxxxx
Subject: sql - group by clause, aggregate returning first record values for rest of fields.
I have a file with 6 fields, I want to aggregate by the first three fields (jobname, user, jobnumber), I want to return the "first values found" for the rest of the fields in the file.
I can get min() to kinda work, but that is field dependent.
select usrinusr, usrinjob, usrinnbr, usrinlvl, usrinpgm, usrintstmp
from mgpll/usrinpf1 group by usrinusr, usrinjob, usrinnbr order by
usrinnbr
I want to return the values in the first record returned for the group record by usrinusr, usrinjob, usrinnbr...
--
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.
--
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.
--
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.
As an Amazon Associate we earn from qualifying purchases.
This mailing list archive is Copyright 1997-2024 by midrange.com and David Gibbs as a compilation work. Use of the archive is restricted to research of a business or technical nature. Any other uses are prohibited. Full details are available on our policy page. If you have questions about this, please contact [javascript protected email address].
Operating expenses for this site are earned using the Amazon Associate program and Google Adsense.