RE: trouble with sql

  • From: "Boyle, Christopher" <Christopher.Boyle@xxxxxxxxxxxxx>
  • To: <chris_stephens@xxxxxxxxxxxx>, <oracle-l@xxxxxxxxxxxxx>
  • Date: Wed, 3 Jan 2007 16:32:36 -0500

Okay, this might have a better explain plan  (assuming 9i or above)

 

with ps2 as ( select/*+ materialize */ p.periodID, ps.projectNumber,
max(ps.changeDate) as changeDate

 from period p, projectStatus ps

 where ps.changeDate >= trunc( p.startDate )

       and trunc( ps.changeDate ) <= p.endDate

 group by p.periodID, ps.projectNumber )

 select ps2.periodID, ps2.projectNumber, ps2.changeDate, ps3.statusID

 from ps2, projectStatus ps3

where ps2.projectNumber = ps3.projectNumber and ps2.changeDate =
ps3.changeDate;

 

but I cant tell without table definitions.  Can a project have more than
one active status?  From the query I would guess that the max change
date indicates the current status but I am not sure.  Can periods
overlap?  

 

Chris

 

  _____  

From: oracle-l-bounce@xxxxxxxxxxxxx
[mailto:oracle-l-bounce@xxxxxxxxxxxxx] On Behalf Of Stephens, Chris
Sent: Wednesday, January 03, 2007 3:34 PM
To: oracle-l@xxxxxxxxxxxxx
Subject: trouble with sql

 

There has got to be a way to do this but I can't find the syntax. 

 

Essentially I need the max of column 3 grouped by column 1 and 2 and
also the value of column 4 that corresponds to the returned columns 1,2,
and 3.

 

Here is the actual sql that I believe to be using an unnecessary join:

select ps2.periodID, ps2.projectNumber, ps2.changeDate, ps3.statusID
from ( select p.periodID, ps.projectNumber, max(ps.changeDate) as
changeDate
 from period p, projectStatus ps
 where ps.changeDate >= trunc( p.startDate )
       and trunc( ps.changeDate ) <= p.endDate
 group by p.periodID, ps.projectNumber ) ps2, projectStatus ps3
where ps2.projectNumber = ps3.projectNumber and ps2.changeDate =
ps3.changeDate

 

Is there a better way to write this?

 


CONFIDENTIALITY NOTICE: 
This message is intended for the use of the individual or entity to
which it is addressed and may contain information that is privileged,
confidential and exempt from disclosure under applicable law. If the
reader of this message is not the intended recipient or the employee or
agent responsible for delivering this message to the intended recipient,
you are hereby notified that any dissemination, distribution or copying
of this communication is strictly prohibited. If you have received this
communication in error, please notify us immediately by email reply. 
______________________________________________________________________
This email has been scanned by the MessageLabs Email Security System.
For more information please visit http://www.messagelabs.com/email 
______________________________________________________________________



NOTICE OF CONFIDENTIALITY: Information included in and/or attached to this 
electronic mail transmission may be confidential. This electronic mail 
transmission is intended for the addressee(s) only. Any unauthorized 
disclosure, reproduction, or distribution of, and/or any unauthorized action 
taken in reliance on the information in this electronic mail is prohibited. If 
you believe that you have received this electronic mail transmission in error, 
please notify the sender by reply transmission, or contact 
helpdesk@xxxxxxxxxxxxx, and delete the message without copying or disclosing 
it. 

______________________________________________________________________
This email has been scanned by the MessageLabs Email Security System.
For more information please visit http://www.messagelabs.com/email 
______________________________________________________________________

Other related posts: