Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> RE: Tricky query question

RE: Tricky query question

From: <Jared.Still_at_radisys.com>
Date: Fri, 24 Jan 2003 16:53:47 -0800
Message-ID: <F001.0053A478.20030124165347@fatcity.com>


No offense Waleed, but the solution Larry suggested is quite a bit easier to take. :)

SQL> l
  1 select primarykey,

  2         status,
  3         dateinserted,
  4         LAG(status,1) OVER (PARTITION BY primarykey
  5                             ORDER BY dateinserted) prior_status
  6* from tricky
SQL> / It also performs better.

Jared

"Khedr, Waleed" <Waleed.Khedr_at_FMR.COM>
Sent by: root_at_fatcity.com
 01/24/2003 02:40 PM
 Please respond to ORACLE-L  

        To:     Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com>
        cc: 
        Subject:        RE: Tricky query question


This works :

create table test_event ( mypk number , mystatus char , mydate date));

insert into test_event values ( 1 , 'A', to_date('01/01/2001','mm/dd/yyyy'));
insert into test_event values ( 1 , 'A', to_date('01/02/2001','mm/dd/yyyy'));
insert into test_event values ( 1 , 'B', to_date('01/03/2001','mm/dd/yyyy'));
insert into test_event values ( 1 , 'B', to_date('01/04/2001','mm/dd/yyyy'));
insert into test_event values ( 1 , 'C', to_date('01/05/2001','mm/dd/yyyy'));
insert into test_event values ( 1 , 'C', to_date('01/06/2001','mm/dd/yyyy'));
insert into test_event values ( 1 , 'A', to_date('01/07/2001','mm/dd/yyyy'));
insert into test_event values ( 1 , 'A', to_date('01/08/2001','mm/dd/yyyy'));
insert into test_event values ( 1 , 'D', to_date('01/09/2001','mm/dd/yyyy'));
insert into test_event values ( 1 , 'D', to_date('01/11/2001','mm/dd/yyyy'));
insert into test_event values ( 1 , 'D', to_date('01/21/2001','mm/dd/yyyy'));
insert into test_event values ( 1 , 'B', to_date('01/22/2001','mm/dd/yyyy'));
insert into test_event values ( 2 , 'F', to_date('01/01/2001','mm/dd/yyyy'));
insert into test_event values ( 2 , 'F', to_date('01/02/2001','mm/dd/yyyy'));
insert into test_event values ( 2 , 'A', to_date('01/03/2001','mm/dd/yyyy'));
insert into test_event values ( 2 , 'A', to_date('01/04/2001','mm/dd/yyyy'));
insert into test_event values ( 2 , 'A', to_date('01/05/2001','mm/dd/yyyy'));
insert into test_event values ( 2 , 'F', to_date('01/06/2001','mm/dd/yyyy'));
insert into test_event values ( 2 , 'R', to_date('01/07/2001','mm/dd/yyyy'));
insert into test_event values ( 2 , 'T', to_date('01/08/2001','mm/dd/yyyy'));
insert into test_event values ( 3 , 'Y', to_date('01/09/2001','mm/dd/yyyy'));
insert into test_event values ( 3 , 'Y', to_date('01/11/2001','mm/dd/yyyy'));
insert into test_event values ( 3 , 'Y', to_date('01/21/2001','mm/dd/yyyy'));
insert into test_event values ( 3 , 'Z', to_date('01/22/2001','mm/dd/yyyy'));

commit;

select a.mypk,b.mydate,b.mystatus
from
  (select rownum myseq,mypk,mystatus,mydate    from (select mypk,mystatus,mydate

          from  test_event
          order by mypk,mydate)) a,

  (select rownum myseq,mypk,mystatus,mydate    from (select mypk,mystatus,mydate
          from  test_event
          order by mypk,mydate)) b 
where a.mypk  = b.mypk

  and a.myseq = b.myseq - 1
  and a.mystatus <> b.mystatus
order by 1,2
MYPK             MYDATE                      MYSTATUS
1                1/3/2001 12:00:00 AM            B
1                1/5/2001 12:00:00 AM            C
1                1/7/2001 12:00:00 AM            A
1                1/9/2001 12:00:00 AM            D
1                1/22/2001 12:00:00 AM           B
2                1/3/2001 12:00:00 AM            A
2                1/6/2001 12:00:00 AM            F
2                1/7/2001 12:00:00 AM            R
2                1/8/2001 12:00:00 AM            T
3                1/22/2001 12:00:00 AM           Z

Regards,

Waleed

-----Original Message-----
Sent: Thursday, January 23, 2003 10:04 PM To: Multiple recipients of list ORACLE-L

Hi All,

This is a question for those who like writing tricky queries as a single SQL... Assume I have a table with the following structure (imaginary table to keep
example simple):

primarykey number(8)
status char(1)
dateinserted date
<many other fields which are insignificant>

A row is inserted into this table any time one, or more, fields change for the record. What I'm trying to determine is the "dateinserted" for each time the value of "status" changed - remembering that there might be 50 records for the primary key and five of those include a change in status - I want the dates of those five records (plus the value of status at each date).

Is there any way to achieve this within a single SQL statement? I realise that I could cursor through each record in date order and use a variable to
store the previous value of status - but I'd love to compress this to a single statement. I've seen the syntax "OVER" used in some queries and suspect this may be useful but I really don't understand it enough to know.

Thanks in advance if you can help me on this one,

Mark.

<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<---->>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>

>>>>

   Privileged/Confidential information may be contained in this message.

          If you are not the addressee indicated in this message
       (or responsible for delivery of the message to such person),
            you may not copy or deliver this message to anyone.
In such case, you should destroy this message and kindly notify the sender
           by reply e-mail or by telephone on (61 3) 9612-6999.
   Please advise immediately if you or your employer does not consent to
                Internet e-mail for messages of this kind.
        Opinions, conclusions and other information in this message
              that do not relate to the official business of
                         Transurban City Link Ltd
         shall be understood as neither given nor endorsed by it.
<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<---->>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>

>>>>
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Mark Richard
  INET: mrichard_at_transurban.com.au

Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
San Diego, California        -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Khedr, Waleed
  INET: Waleed.Khedr_at_FMR.COM

Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
San Diego, California        -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).




-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: 
  INET: Jared.Still_at_radisys.com

Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
San Diego, California        -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).
Received on Fri Jan 24 2003 - 18:53:47 CST

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US