× The internal search function is temporarily non-functional. The current search engine is no longer viable and we are researching alternatives.
As a stop gap measure, we are using Google's custom search engine service.
If you know of an easy to use, open source, search engine ... please contact support@midrange.com.



So it's the Where statement I need to pay attention to in addition to the Order By when determining which fields to make the key fields in my index?

I gave #2 a try and it worked. I can't use #1 because after the read there is a lot of stuff happening before the update.

I changed the Select to also have:
For Update of StmDte, Corp#, Loc#, Dept#, PrtFlg, SvPrtFlg

Although in doing this it was no longer fetching for 250 like my statement requests, and instead was fetching 2 at a time.

-Kurt

-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx [mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Charles Wilt
Sent: Tuesday, June 22, 2010 4:09 PM
To: Midrange Systems Technical Discussion
Subject: Re: Creating SQL Index

Kurt,

You've picked the worst of both worlds here...

You're using a cusor to read the file, then doing separate updates.
Basically, you're reading each record twice.

You need to either:
1) Do a set based update
Update CdrMstP a
Set StmDte = :StmtDate,
Corp# = :Corp#,
Loc# = :ds_CdrOut.Loc#,
Dept# = :ds_CdrOut.Dept#,
PrtFlg = :ds_CdrOut.PrtFlg,
SvPrtFlg = :ds_CdrOut.SvPrtFlg
Where Cust# = :Cust# and CalDte <= :CutOff
and StmDte = '0001-01-01'

2) UPDATE .... WHERE CURRENT OF CURSOR syntax


Option one is preferred. In fact, Unless you do this one demand, for
one customer at a time you should probably have a statement that looks
like so:
Update CdrMstP a
Set StmDte = :StmtDate,
Corp# = :Corp#,
Loc# = :ds_CdrOut.Loc#,
Dept# = :ds_CdrOut.Dept#,
PrtFlg = :ds_CdrOut.PrtFlg,
SvPrtFlg = :ds_CdrOut.SvPrtFlg
Where CalDte <= :CutOff
and StmDte = '0001-01-01'


If you continue to use a cursor, the "perfect" index would be
CREATE INDEX CdrMst_x01
ON CdrMstP (StmDte, Cust#, CalDte)

for a slightly modified statement (note the addition of StmDte to the Order By):
Select Cust#, CalDte, Pac#, Dept#, CalTyp, DstFlg, BAmt, DspQty,
Loc#, PrtFlg, SvPrtFlg, RRN(a)
From CdrMstP a
Where Cust# = :Cust# and CalDte <= :CutOff
and StmDte = '0001-01-01'
Order By StmDte, Cust#, CalDte;

But given that you intend to update one of the index fields, I don't
believe the system will use the perfect index.

HTH,
Charles

On Tue, Jun 22, 2010 at 4:19 PM, Kurt Anderson
<kurt.anderson@xxxxxxxxxxxxxx> wrote:
I have a procedure in a service program that I'd like to change to use SQL, but I can't seem to get my finger on how the index should look so the optimizer picks it up.  Here is the SQL in the procedure.  The select is actually a part of a declare.  I'm fetching 250 rows at a time, and updating every row.

           Select Cust#, CalDte, Pac#, Dept#, CalTyp, DstFlg, BAmt, DspQty,
                  Loc#, PrtFlg, SvPrtFlg, RRN(a)
             From CdrMstP a
            Where Cust# = :Cust# and CalDte <= :CutOff
              and StmDte = '0001-01-01'
         Order By Cust#, CalDte;

          Update CdrMstP a
          Set StmDte = :StmtDate,
              Corp# = :Corp#,
              Loc# = :ds_CdrOut.Loc#,
              Dept# = :ds_CdrOut.Dept#,
              PrtFlg = :ds_CdrOut.PrtFlg,
              SvPrtFlg = :ds_CdrOut.SvPrtFlg
          where rrn(a) = :ds_CDROut.CdrRRN;


Index attempts:

1.  Doesn't like that a key field is getting updated.
CREATE INDEX CdrMst_x01
  ON CdrMstP (Cust#, CalDte, Pac#, Dept#, CalTyp, DstFlg, BAmt, DspQty,
              Loc#, PrtFlg, SvPrtFlg);

2.  I think it doesn't like that my key doesn't include all the fields in the select
CREATE INDEX CdrMst_x01
  ON CdrMstP (Cust#, CalDte)

Any thoughts?
I'm on v5r4.

Thanks,
Kurt Anderson
Sr. Programmer/Analyst
CustomCall Data Systems
--
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.



As an Amazon Associate we earn from qualifying purchases.

This thread ...

Follow-Ups:
Replies:

Follow On AppleNews
Return to Archive home page | Return to MIDRANGE.COM home page

This mailing list archive is Copyright 1997-2024 by midrange.com and David Gibbs as a compilation work. Use of the archive is restricted to research of a business or technical nature. Any other uses are prohibited. Full details are available on our policy page. If you have questions about this, please contact [javascript protected email address].

Operating expenses for this site are earned using the Amazon Associate program and Google Adsense.