There was a wron < within my previous example:
Here is the modified SELECT-Statement
Select Ticket,
lead(Ticket) Over(Order By Ticket) as NextTicket,
lead(Ticket, 1, 0) Over(Order By Ticket) - Ticket as Gap
From myGap
Order BY Gap Desc
Mit freundlichen Grüßen / Best regards
Birgitta Hauser
"Shoot for the moon, even if you miss, you'll land among the stars." (Les
Brown)
"If you think education is expensive, try ignorance." (Derek Bok)
"What is worse than training your staff and losing them? Not training them
and keeping them!"
?Train people well enough so they can leave, treat them well enough so they
don't want to.? (Richard Branson)
-----Original Message-----
From: MIDRANGE-L [mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of
Birgitta Hauser
Sent: Freitag, 20. Januar 2017 08:38
To: 'Midrange Systems Technical Discussion' <midrange-l@xxxxxxxxxxxx>
Subject: RE: SQL to show largest gaps
If you are already on release 7.3, you may use one of the new OLAP functions
as follows:
Select Ticket,
lead(Ticket) Over(Order By Ticket) as NextTicket,
lead(Ticket, 1, 0) Over(Order By Ticket) - Ticket as Gap
From myGap
Order BY Gap Desc
Lag() Over() returns the next row value within the sequence (i.e. depending
on the Order By Clause within the Over() clause.
The first parameter in the LAG function is the data column, the second one
is the number of steps go further (default = 1) and the third column is a
default value to be set if no sub-sequent value is found (Default = NULL).
So the second column in my SELECT statement returns the NextTicket.
For calculating the gap the second column is not necessary. The lag function
can also be used directly in a calculation (as shown in column 3).
This result only needs to be ordered by the GAP in descending sequence
Mit freundlichen Grüßen / Best regards
Birgitta Hauser
"Shoot for the moon, even if you miss, you'll land among the stars." (Les
Brown)
"If you think education is expensive, try ignorance." (Derek Bok) "What is
worse than training your staff and losing them? Not training them and
keeping them!"
?Train people well enough so they can leave, treat them well enough so they
don't want to.? (Richard Branson)
-----Original Message-----
From: MIDRANGE-L [mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of T.
Adair
Sent: Donnerstag, 19. Januar 2017 17:25
To: midrange-l@xxxxxxxxxxxx
Subject: SQL to show largest gaps
I have a physical file with a ticket# field (5,0). It should be mostly in
sequence with small gaps. Unfortunately there are some large gaps and I
need to track those down. I am an SQL novice but I'm trying to use SQL to
show the gaps. As in...
Tkt# Next Tkt# Gap
1 2 1
2 3 1
3 7 4
7 8 1
8 13 5
13 15 2
15 335 220
335 336 1
Etc.
But, I would like it to show this in sequence by gap size (desc), as in...
Tkt# Next Tkt# Gap
15 335 220
8 13 5
3 7 4
13 15 2
1 2 1
2 3 1
Etc.
Here's my latest attempt (please don't laugh at my mess).
select a.ticket#,
(select ticket# from fileb b
where b.ticket# > a.ticket#
fetch first 1 row only ),
b.ticket# - a.ticket# as gap
from filea a
order by gap desc
It tells me, "Column or global variable TICKET# not found."
I've searched the archives but didn't find anything like this. Am I even on
the right track?
Thoughts? Advice? Suggestions?
Thanks in advance.
~TA~
--
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.
Please contact support@xxxxxxxxxxxx for any subscription related questions.
Help support midrange.com by shopping at amazon.com with our affiliate link:
http://amzn.to/2dEadiD
--
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.
Please contact support@xxxxxxxxxxxx for any subscription related questions.
Help support midrange.com by shopping at amazon.com with our affiliate link:
http://amzn.to/2dEadiD
As an Amazon Associate we earn from qualifying purchases.