Re: trouble with sql

  • From: Stephane Faroult <sfaroult@xxxxxxxxxxxx>
  • To: chris_stephens@xxxxxxxxxxxx
  • Date: Wed, 03 Jan 2007 22:43:12 +0100

Chris,

The other solution is to use an analytical function - or to use max() as an analytical function,
eg

select p.periodID, ps.projectNumber, ps.changeDate, ps.statusID
from (select ps.projectNumber,
max(ps.changeDate) over (partition by projectNumber) as maxchangeDate,
                  changeDate,
                  statusID
         from projectStatus) ps,
       period p
where ps.changeDate = ps.maxChangeDate
and ps.changeDate between trunc(p.startDate) and trunc(p.endDate + 1) - 1/86400

Also, be careful about your comparison with the period table - especially your trunc() that are applied in one case to a column from one table, and in the other case to a column from the other table. This doesn't help with joins, although in this particular case it may not matter much. But your solution is not necessarily bad. It really depends on how data is stored. However, if, as can be expected, (projectNumber, changeDate) is the PK of the projectStatus table, the analytical function can be cheaply evaluated.

HTH

Stephane Faroult


Stephens, Chris wrote:
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.

--
//www.freelists.org/webpage/oracle-l


Other related posts: