Ah, yes, Jeff has restored my memory (below). If your application does not use bind variables, then you have many more "distinct" SQL statements than you actually *should* have. ...Which is another reason that collecting the SQL is such an important step. If you do it with too simple of a matching algorithm, then you're accidentally giving yourself (and your system) way too much work. For example, SELECT ID FROM T WHERE LNAME='Smith' and SELECT ID FROM T WHERE LNAME='Jones' should really be regarded as one distinct statement.
Cary Millsap Hotsos Enterprises, Ltd. http://www.hotsos.com Upcoming events: - Hotsos Clinic 101, Jan 7-9 Knoxville - Steve Adams's Miracle Master Class, Jan 13-15 Copenhagen - 2003 Hotsos Symposium, Feb 9-12 Dallas -----Original Message----- Sent: Monday, December 23, 2002 1:06 PM To: 'Cary Millsap' That approach would work as long as you can predict the number of distinct statements over the observation interval. If you can predict the number of distinct statements, then you can attempt to size the tablespace. If you cannot predict the volume, then you risk filling the tablespace where the outlines are stored. The most common cause for not being able to predict is an application's lack of use of bind variables in its statements. I haven't tested the scenario of create_stored_outlines=true and the outline cannot be stored because of some error such as 'table cannot be extended'. I would hope that it would ignore the insert error but without a test it would be somewhat risky. Especially since the creations would be most likely be executed on a production instance. Jeff Holt - An O2 bottle, an O2 bottle! My password for an O2 bottle! Hotsos Enterprises, Ltd. http://www.hotsos.com Upcoming events at http://www.hotsos.com/events/index.html -----Original Message----- Sent: Mon, Dec 23, 2002 09:40 To: [EMAIL PROTECTED] We assessed this and discarded the option, and now I can't remember why (I'll get back to you after I ask Jeff Holt, who did the study). At best, using stored outlines is a replacement only for steps 2 and 4. The really hard part is step 1. Cary Millsap Hotsos Enterprises, Ltd. http://www.hotsos.com Upcoming events: - Hotsos Clinic 101, Jan 7-9 Knoxville - Steve Adams's Miracle Master Class, Jan 13-15 Copenhagen - 2003 Hotsos Symposium, Feb 9-12 Dallas -----Original Message----- [EMAIL PROTECTED] Sent: Monday, December 23, 2002 6:14 AM To: Multiple recipients of list ORACLE-L Cary, I assume that using stored outlines will achieve No 2 in your list. Would that not be an easier approach? If you altered the system to have CREATE_STORED_OUTLINES=true and ran for a period when all scripts are likely to be run, say a month so that all month-end processing was completed, and then check the OUTLN.OL$HINTS.HINT_TEXT column with a query such as the following. 1 select hint_text from outln.ol$hints 2* where substr(hint_text,1,5) = 'INDEX' SQL> / HINT_TEXT ------------------------------------------------------------------------ ---- ---- INDEX(SIMPLE_PK_5M SIMPLE_PK) HTH John -----Original Message----- Sent: 23 December 2002 05:59 To: Multiple recipients of list ORACLE-L Mark, The way we do it is by what you might call extreme brute force: 1. Capture all SQL from the applications (not just the stuff you've run in the past month, but the stuff you'll run in the future too, like period-end close processes, and so on). 2. Generate execution plans in production for all this SQL. Store the plans. 3. In a "structural replica" system (that is, a full-schema test instance; you don't need real application data, but you do need schema and db statistics imported from the production system), drop the index. 4. Generate execution plans on the replica system for all the SQL. Store the plans. 5. Compare the two sets of plans from steps 2 and 4. 6. Decide whether the different in 4 that are different from the plans in 2 are better or worse than the plans in 2. Like I said, it's a "big hammer" method, but it has its reliability advantages, and the only step that we haven't automated is #6. (I'm assuming that you already have a valid test system as described in #3.) The tool we use that does steps 2, 4, and 5 is called Project Laredo (www.hotsos.com/products/laredo). Cary Millsap Hotsos Enterprises, Ltd. http://www.hotsos.com Upcoming events: - Hotsos Clinic 101, Jan 7-9 Knoxville - Steve Adams's Miracle Master Class, Jan 13-15 Copenhagen - 2003 Hotsos Symposium, Feb 9-12 Dallas -----Original Message----- Richard Sent: Sunday, December 22, 2002 10:54 PM To: Multiple recipients of list ORACLE-L Dear List, Firstly - Merry Christmas to those who have not already departed for the holiday season. I'm currently doing some investigation based around indexes and would like everyone's opinion: What is everyone's preferred approach to identify redundant (as in "never used by Oracle") indexes? I believe Oracle 9 might have a feature to set a flag on objects and then check back later to see if they have been accessed however we're still stuck on 8.1.7.4 (Solaris). Some of my thoughts include: * Can query for physical disk i/o at a tablespace level easily, however more difficult to go to an object level. * Could create a trace file and then inspect explain plans for existence of index accesses, however trace file probably not practical to capture for a long period of time. * Ideal statistic would be something along the lines of "index x used y times in last 24 hours", however a simple "index x was used in the last 24 hours" would be ok. Obviously we are searching for indexes to remove and identifying those which aren't queried over a set period of time would be good candidates for a starting point. Any advice you might have would be greatly appreciated. Regards, Mark. <<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<---->>>>>>>>>>>>>>>>>>>>>>>>>>>>>> >>>>>>>> Privileged/Confidential information may be contained in this message. If you are not the addressee indicated in this message (or responsible for delivery of the message to such person), you may not copy or deliver this message to anyone. In such case, you should destroy this message and kindly notify the sender by reply e-mail or by telephone on (61 3) 9612-6999. Please advise immediately if you or your employer does not consent to Internet e-mail for messages of this kind. Opinions, conclusions and other information in this message that do not relate to the official business of Transurban City Link Ltd shall be understood as neither given nor endorsed by it. <<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<---->>>>>>>>>>>>>>>>>>>>>>>>>>>>> >>>>>>>> -- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: Mark Richard INET: [EMAIL PROTECTED] Fat City Network Services -- 858-538-5051 http://www.fatcity.com San Diego, California -- Mailing list and web hosting services --------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: [EMAIL PROTECTED] (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing). -- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: Cary Millsap INET: [EMAIL PROTECTED] Fat City Network Services -- 858-538-5051 http://www.fatcity.com San Diego, California -- Mailing list and web hosting services --------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: [EMAIL PROTECTED] (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing). -- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: <[EMAIL PROTECTED] INET: [EMAIL PROTECTED] Fat City Network Services -- 858-538-5051 http://www.fatcity.com San Diego, California -- Mailing list and web hosting services --------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: [EMAIL PROTECTED] (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing). -- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: Cary Millsap INET: [EMAIL PROTECTED] Fat City Network Services -- 858-538-5051 http://www.fatcity.com San Diego, California -- Mailing list and web hosting services --------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: [EMAIL PROTECTED] (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing).
