On 8/31/05, S. Isaac Dealey <[EMAIL PROTECTED]> wrote:
> >> > In Oracle, there is ROWNUM...
> >>
> >> Yeah, but that's not how you get a set out of the middle
> >> with Oracle,
> >> 'cause if you specify a minimum value for rownum you
> >> don't get the
> >> expected results... well... not by itself... In oracle
> >> you use the
> >> MINUS clause, which is surprisingly efficient... but... I
> >> still don't
> >> recommend using it, just because I advocate db
> >> independance.
> >>
> >> SELECT * FROM mytable WHERE rownum < 100
> >> ORDER BY my, column, list
> >>
> >> MINUS SELECT * FROM mytable WHERE rownum > 50
> >> ORDER BY my, column, list
> 
> > note, the ORDER BY occurs after the WHERE clause, so this
> > may not give
> > the results you are expecting.
> 
> I was lead to believe this was one of the uses the folks at Oracle had
> intended for the MINUS clause, and it did work when I needed it... I'm
> just thankfull I haven't needed it since then.

right.  Its a matter of do you want 
a) row 50 - 100 then sort them by mycolumn
or
b) sort by mycolumn then get row 50 to 100.

your example will handle a but not b.  The rownum gets assigned prior
to ordering.  Thinking about this, your example may not always get a
as expected since the rownum assignment may not be well defined.

Something like this works for b

SELECT * FROM (
  SELECT a.*, rownum as rn FROM (
     SELECT * FROM mytable ORDER BY mycolumn) a
  ) WHERE rn BETWEEN 50 AND 100


to get a definitively 
SELECT * FROM (
  SELECT a.*, rownum as rn FROM mytable a
  ) WHERE rn BETWEEN 50 AND 100
 ORDER BY mycolumn



DK
> 
> s. isaac dealey   954.522.6080
> new epoch : isn't it time for a change?
> 
> add features without fixtures with
> the onTap open source framework
> 
> http://www.fusiontap.com
> http://coldfusion.sys-con.com/author/4806Dealey.htm
> 
> 
> 
> 
> 

~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~|
Logware (www.logware.us): a new and convenient web-based time tracking 
application. Start tracking and documenting hours spent on a project or with a 
client with Logware today. Try it for free with a 15 day trial account.
http://www.houseoffusion.com/banners/view.cfm?bannerid=67

Message: http://www.houseoffusion.com/lists.cfm/link=i:4:217014
Archives: http://www.houseoffusion.com/cf_lists/threads.cfm/4
Subscription: http://www.houseoffusion.com/lists.cfm/link=s:4
Unsubscribe: http://www.houseoffusion.com/cf_lists/unsubscribe.cfm?user=89.70.4
Donations & Support: http://www.houseoffusion.com/tiny.cfm/54

Reply via email to