Re: stale partition statistics

From: Mikhail Velikikh <mvelikikh_at_gmail.com>
Date: Mon, 8 Mar 2021 19:12:58 +0000
Message-ID: <CALe4Hp=ccU=Q-DJMern9-YtGOLi6qT_Qeb_byP_P1KFaWEFnyQ_at_mail.gmail.com>



Hi Nenad,

I got the same flags after one database upgrade from 12.2 to 19.7. Basically, there was a list partitioned table, and the gather stats job started collecting statistics on the table's indexes everyday following the 19.7 upgrade (I believe on the global ones). While I was investigating the issue, I found that some of data dictionary views were looking at that MON_MODS_V.FLAGS to determine the staleness - that is why the statistics were regathered every day. The exact meaning of that flags value is somewhere in DBMS_STATS or the packages calling from it - at least that is where I found it then.

I checked my notes, and I tried several different things to get stats back to normal, such as:
exec dbms_stats.delete_table_stats('owner', 'table_name', stat_category=> 'OBJECT_STATS,SYNOPSES')
exec dbms_stats.gather_table_stats('owner', 'table_name')

The statistics preferences were as follows: SQL> SELECT
  2 owner, table_name,
  3
 DBMS_STATS.get_prefs(ownname=>USER,tabname=>table_name,pname=>'INCREMENTAL') incremental,
  4
 DBMS_STATS.get_prefs(ownname=>USER,tabname=>table_name,pname=>'GRANULARITY') granularity,
  5
 DBMS_STATS.get_prefs(ownname=>USER,tabname=>table_name,pname=>'STALE_PERCENT') stale_percent,
  6
 DBMS_STATS.get_prefs(ownname=>USER,tabname=>table_name,pname=>'ESTIMATE_PERCENT') estimate_percent,
  7
 DBMS_STATS.get_prefs(ownname=>USER,tabname=>table_name,pname=>'CASCADE') cascade,
  8 DBMS_STATS.get_prefs(pname=>'METHOD_OPT') method_opt   9 FROM dba_tables
 10 WHERE table_name ='table_name'
 11 and owner='owner'
 12 ORDER BY owner, table_name;

OWNER      TABLE_NAME           INCREMENTAL          GRANULARITY
 STALE_PERCENT        ESTIMATE_PERCENT               CASCADE

    METHOD_OPT

---------- -------------------- -------------------- --------------------
-------------------- ------------------------------
------------------------- -------------------------
owner         table_name TRUE                 AUTO                 10
            DBMS_STATS.AUTO_SAMPLE_SIZE    DBMS_STATS.AUTO_CASCADE   FOR
ALL COLUMNS SIZE 1 There was also INCREMENTAL_STALENESS=USE_STALE_PERCENT set.

The way I checked the flags is using the query like this: select * from sys.optstat_snapshot$ where obj#=185925 order by timestamp;

      OBJ# INSERTS UPDATES DELETES FLAGS TIMESTAMP ---------- ---------- ---------- ---------- ----------


    185925 165103 557906 0 0 11-MAY-20 10.18.43.791891 PM -04:00

    185925 603978 558015 0 0 11-MAY-20 11.18.47.734575 PM -04:00

    185925 673059 558524 0 0 12-MAY-20 01.03.54.386869 AM -04:00

    185925 1294183 605041 0 0 12-MAY-20 02.03.58.300521 AM -04:00

    185925 1358957 692646 0 40 12-MAY-20 02.35.52.733528 AM -04:00

    185925 0 242425 0 0 12-MAY-20 03.34.04.838415 AM -04:00

    185925 0 242425 0 40 12-MAY-20 03.59.42.940827 AM -04:00

    185925 0 1 0 40 12-MAY-20 04.08.15.887380 AM -04:00

    185925 0 0 0 40 12-MAY-20 04.15.45.580398 AM -04:00

    185925 0 638 0 40 12-MAY-20 04.25.43.490814 AM -04:00

    185925 0 278 0 40 12-MAY-20 04.35.57.022339 AM -04:00

    185925 0 8581 0 40 12-MAY-20 04.45.40.478107 AM -04:00

    185925 0 85532 0 40 12-MAY-20 04.55.37.699201 AM -04:00

    185925 89737 0 0 0 17-MAY-20 10.32.00.757830 PM -04:00

    185925 175288 13533 0 0 17-MAY-20 11.32.05.038541 PM -04:00

    185925 175288 13533 0 0 18-MAY-20 12.32.08.422136 AM -04:00

    185925 175288 13533 0 0 18-MAY-20 01.32.12.059589 AM -04:00

    185925 175288 13533 0 40 18-MAY-20 02.32.01.836936 AM -04:00

    185925 0 0 0 40 18-MAY-20 03.33.57.325283 AM -04:00

    185925 12005 0 0 0 18-MAY-20 08.44.27.382584 AM -04:00

    185925 12005 941 0 0 18-MAY-20 09.44.29.421376 AM -04:00

    185925 12005 4159 0 0 18-MAY-20 10.44.32.184351 AM -04:00

    185925 12005 5365 0 0 18-MAY-20 11.44.33.433158 AM -04:00

    185925 12005 5365 0 0 18-MAY-20 12.44.34.162253 PM -04:00

    185925 12005 5365 0 0 18-MAY-20 01.44.35.163062 PM -04:00

    185925 12005 5365 0 0 18-MAY-20 02.44.36.352044 PM -04:00

    185925 12005 5365 0 0 18-MAY-20 03.44.37.308166 PM -04:00

    185925 12005 5365 0 0 18-MAY-20 04.44.38.309023 PM -04:00

    185925 12005 5365 0 0 18-MAY-20 05.44.39.285316 PM -04:00

    185925 12005 5365 0 0 18-MAY-20 06.44.40.241425 PM -04:00

    185925 12005 5365 0 0 18-MAY-20 07.44.41.296872 PM -04:00

    185925 12005 5365 0 0 18-MAY-20 08.44.42.524968 PM -04:00

    185925 12005 5365 0 0 18-MAY-20 09.44.43.561849 PM -04:00

    185925 12005 5365 0 0 18-MAY-20 10.44.44.638588 PM -04:00

    185925 12005 5365 0 0 18-MAY-20 11.44.48.566198 PM -04:00

    185925 12005 5365 0 0 19-MAY-20 12.44.49.587112 AM -04:00

    185925 12005 5365 0 0 19-MAY-20 01.44.50.610348 AM -04:00

    185925 12005 5365 0 8 19-MAY-20 03.29.52.937021 AM -04:00

    185925 12005 5365 0 8 19-MAY-20 04.29.54.274754 AM -04:00
..skip...

    185925 39055 55056337 0 8 22-MAY-20 01.52.22.127686 PM -04:00

    185925 39055 55056337 0 8 22-MAY-20 02.52.23.180742 PM -04:00

    185925 39055 55056337 0 8 22-MAY-20 03.52.24.267023 PM -04:00

    185925 39055 55056337 0 40 22-MAY-20 04.24.02.507669 PM -04:00

    185925 0 0 0 8 23-MAY-20 04.37.38.529168 AM -04:00

I think I hit that issue in multiple environments. The flags was set to 8 following the upgrade and then I could not get rid of it. Raised an SR with Oracle, but it went nowhere. The flags switching from 8 to 40 and backwards might be due to the statistics gathering - cannot recall.

On Mon, 8 Mar 2021 at 18:55, Noveljic Nenad <nenad.noveljic_at_vontobel.com> wrote:

> The statistics were gathered as follows:
>
>
>
> SYS.DBMS_STATS.GATHER_SCHEMA_STATS (
>
> OwnName => ‘USER',
>
> Options => 'GATHER STALE',
>
> Method_Opt => 'FOR ALL COLUMNS SIZE REPEAT ',
>
> Degree => 4,
>
> Cascade => TRUE,
>
> No_Invalidate => FALSE);
>
>
>
> All partitions had stale_stats = ‘NO’. Tthe amount of changes didn’t
> exceed the staleness thresholds.
>
>
>
> Yet the gather_schema_stats considered the statistics stale because of
> MON_MODS_V.flags=8 on all partitions. The number of modifications isn’t the
> only criteria for staleness. Gather_schema_stats dropped and recalculated
> all the synopses for this table.
>
>
>
> Interestingly, when I executed gather_table_stats, synopses weren’t
> recreated, even when flags=8.
>
>
>
> My entertainment for tomorrow is to figure out what set MON_MODS_V .flags
> to 8, unless somebody knows the answer. Truncate, for example, sets it to
> 1.
>
>
>
> Best regards,
>
>
>
> Nenad
>
> ____________________________________________________
>
> Please consider the environment before printing this e-mail.
>
> Bitte denken Sie an die Umwelt, bevor Sie dieses E-Mail drucken.
>
>
> Important Notice
>
> This message is intended only for the individual named. It may contain
> confidential or privileged information. If you are not the named addressee
> you should in particular not disseminate, distribute, modify or copy this
> e-mail. Please notify the sender immediately by e-mail, if you have
> received this message by mistake and delete it from your system.
> Without prejudice to any contractual agreements between you and us which
> shall prevail in any case, we take it as your authorization to correspond
> with you by e-mail if you send us messages by e-mail. However, we reserve
> the right not to execute orders and instructions transmitted by e-mail at
> any time and without further explanation.
> E-mail transmission may not be secure or error-free as information could
> be intercepted, corrupted, lost, destroyed, arrive late or incomplete. Also
> processing of incoming e-mails cannot be guaranteed. All liability of
> Vontobel Holding Ltd. and any of its affiliates (hereinafter collectively
> referred to as "Vontobel Group") for any damages resulting from e-mail use
> is excluded. You are advised that urgent and time sensitive messages should
> not be sent by e-mail and if verification is required please request a
> printed version.
> Please note that all e-mail communications to and from the Vontobel Group
> are subject to electronic storage and review by Vontobel Group. Unless
> stated to the contrary and without prejudice to any contractual agreements
> between you and Vontobel Group which shall prevail in any case,
> e-mail-communication is for informational purposes only and is not intended
> as an offer or solicitation for the purchase or sale of any financial
> instrument or as an official confirmation of any transaction.
> The legal basis for the processing of your personal data is the legitimate
> interest to develop a commercial relationship with you, as well as your
> consent to forward you commercial communications. You can exercise, at any
> time and under the terms established under current regulation, your rights.
> If you prefer not to receive any further communications, please contact
> your client relationship manager if you are a client of Vontobel Group or
> notify the sender. Please note for an exact reference to the affected group
> entity the corporate e-mail signature. For further information about data
> privacy at Vontobel Group please consult www.vontobel.com.
>

--
http://www.freelists.org/webpage/oracle-l
Received on Mon Mar 08 2021 - 20:12:58 CET

Original text of this message