Forum Stats

  • 3,874,790 Users
  • 2,266,774 Discussions
  • 7,911,962 Comments

Discussions

Collecting stats takes forever after adding new index - why?

2»

Answers

  • Jonathan Lewis
    Jonathan Lewis Member Posts: 10,117 Blue Diamond

    Hemant has given you the clue.

    When you create a function-based index Oracle supports it with a virtual column.

    When you gather table stats Oracle evaluates the function for each row in the table - it doesn't try to look at the index to derive the statistics from the index (which, technically, would be possible).

    Your extra time for collecting stats is probably spent hacking through all those LOBs.

    This might be a case where you should add a column and store the result of the function (and then not bother with an index on the column).

    Regards

    Jonathan Lewis

    Jonathan Lewis
  • 978225
    978225 Member Posts: 79
    However, I am stumped by your using it against a LOB.
    
    

    Well, it's just a column. It may contain larger content and be stored differently, but still - it's just a column... Isn't it?

    What sort of queries do you run against the table ?  If the queries are retrieving 90% of the rows and you are retrieving columns other than the return value of the function, Oracle has to go to the table and not use the index.
    
    

    The content of the LOB is XML which is later inserted into an object-relational XmlType column. There are some XMLs that contain a tag (<actions>) which violates the structure, thus I am trying to filter those out. I was using an XPath expression for that but figured that a plain text search should be faster, because that will save the engine the effort of parsing the whole thing in some kind of an XML structure.

    The query is basically a

    INSERT INTO ... SELECT ... from S_RMP_EVALUATION_CSC_MESSAGE
    WHERE DECODE(INSTR("XML_MESSAGE_TEXT",'<actions>'),0,0,1)=0
    

    Then I figured I add the function-based BITMAP index to prevent Oracle from having to re-evaluate at query time and instead just use the pre-calculated index value.

    You are right, it is not a covering index, so Oracle still needs to access the table data to get the other columns for the INSERT, but I figured it would use the index to select the matching records first and then move on to the records in the table. At that point, a lot would have been gained already, compared to evaluating the WHERE condition during query time.

  • 978225
    978225 Member Posts: 79
    When you create a function-based index Oracle supports it with a virtual column.
    

    Ok, so far so good. So the virtual column holds the result of the function.

    When you gather table stats Oracle evaluates the function for each row in the table - it doesn't try to look at the index to derive the statistics from the index (which, technically, would be possible).
    

    This is what I did not expect. If it already has it evaluated and stored in the virtual column, I would have expected it to simply read it from there rather than re-evaluating the function for each record... Are you sure about this?

    Do you happen to know if the same thing is going to happen with a user-declared virtual column? I would be creating the same virtual column as Oracle is doing internally... Guess I'll try that...

    Your extra time for collecting stats is probably spent hacking through all those LOBs.
    This might be a case where you should add a column and store the result of the function (and then not bother with an index on the column).
    

    This would be an explanation for why things take so long. Although I don't see why Oracle wouldn't simply be using the value from the virtual column.

  • Jonathan Lewis
    Jonathan Lewis Member Posts: 10,117 Blue Diamond
    Answer ✓

    It's a VIRTUAL column - Oracle doesn't store the value of the function in the table for each row, it simply stores the description of the defining function as the column definition in the data dictionary.  The index DOES hold the actual calculated value (with the rowid of the row that each value came from), but Oracle doesn't have a mechanism for looking at the index when it's gathering column stats.  (In fact such a mechanism could only be created for a single column index anyway).

    Regards

    Jonathan Lewis

  • Hemant K Chitale
    Hemant K Chitale Member Posts: 15,759 Blue Diamond
    edited Jan 15, 2014 9:11PM

    I actually see the avg_row_len increasing -- as if the computed value is stored with the table.

    SQL> create table hkc_test_fbi_vc as select * from dba_objects where rownum < 100;

    Table created.

    SQL> exec dbms_stats.gather_table_stats('','HKC_TEST_FBI_VC');

    PL/SQL procedure successfully completed.

    SQL> select num_rows, avg_row_len, blocks
      2  from user_tables
      3  where table_name = 'HKC_TEST_FBI_VC';

      NUM_ROWS AVG_ROW_LEN     BLOCKS
    ---------- ----------- ----------
            99          76          5

    1 row selected.

    SQL> create index hkc_test_fbi_vc_ndx on hkc_test_fbi_vc(rpad(owner,100,'X'));

    Index created.

    SQL> exec dbms_stats.gather_table_stats('','HKC_TEST_FBI_VC');

    PL/SQL procedure successfully completed.

    SQL> select num_rows, avg_row_len, blocks
      2  from user_tables
      3  where table_name = 'HKC_TEST_FBI_VC';

      NUM_ROWS AVG_ROW_LEN     BLOCKS
    ---------- ----------- ----------
            99         177          5

    1 row selected.

    SQL>

    As expected, the new column, being virtual, doesn't appear in a describe of the table.

    SQL> desc hkc_test_fbi_vc
    Name                                                                                Null?    Type
    ----------------------------------------------------------------------------------- -------- ---------------

    OWNER                                                                                        VARCHAR2(30)
    OBJECT_NAME                                                                                  VARCHAR2(128)
    SUBOBJECT_NAME                                                                               VARCHAR2(30)
    OBJECT_ID                                                                                    NUMBER
    DATA_OBJECT_ID                                                                               NUMBER
    OBJECT_TYPE                                                                                  VARCHAR2(19)
    CREATED                                                                                      DATE
    LAST_DDL_TIME                                                                                DATE
    TIMESTAMP                                                                                    VARCHAR2(19)
    STATUS                                                                                       VARCHAR2(7)
    TEMPORARY                                                                                    VARCHAR2(1)
    GENERATED                                                                                    VARCHAR2(1)
    SECONDARY                                                                                    VARCHAR2(1)
    NAMESPACE                                                                                    NUMBER
    EDITION_NAME                                                                                 VARCHAR2(30)

    SQL>

    SQL> select column_name, column_id from user_tab_columns
      2  where table_name = 'HKC_TEST_FBI_VC'
      3  order by 2;

    COLUMN_NAME                     COLUMN_ID
    ------------------------------ ----------
    OWNER                                   1
    OBJECT_NAME                             2
    SUBOBJECT_NAME                          3
    OBJECT_ID                               4
    DATA_OBJECT_ID                          5
    OBJECT_TYPE                             6
    CREATED                                 7
    LAST_DDL_TIME                           8
    TIMESTAMP                               9
    STATUS                                 10
    TEMPORARY                              11
    GENERATED                              12
    SECONDARY                              13
    NAMESPACE                              14
    EDITION_NAME                           15

    15 rows selected.

    SQL>

    SQL> select leaf_blocks, blevel, distinct_keys
      2  from user_indexes
      3  where index_name = 'HKC_TEST_FBI_VC_NDX';

    LEAF_BLOCKS     BLEVEL DISTINCT_KEYS
    ----------- ---------- -------------
              2          1             1

    1 row selected.

    SQL>

    (which is OK because all 99 rows have the same OWNER value SYS)

    SQL> select distinct owner from hkc_test_fbi_vc;

    OWNER
    ------------------------------
    SYS

    1 row selected.

    SQL>

    Hemant K Chitale

  • Unknown
    edited Jan 15, 2014 9:59PM
    I actually see the avg_row_len increasing -- as if the computed value is stored with the table.
    . . .
    As expected, the new column, being virtual, doesn't appear in a describe of the table.
     

    That's because that data is sourced from ALL_TAB_COLUMNS which filters hidden columns.

    It shows in ALL_TAB_COLS with an AVG_COL_LEN of 101. Sum up all of those and you get 178.

  • Hemant K Chitale
    Hemant K Chitale Member Posts: 15,759 Blue Diamond

    This was with reference to Jonathan's assertion "Oracle doesn't store the value of the function in the table for each row, it simply stores the description of the defining function as the column definition in the data dictionary"

    I believe that the  actual values derived from the function are stored with each row.

    Hemant K Chitale


  • Unknown
    edited Jan 15, 2014 11:26PM
    This was with reference to Jonathan's assertion "Oracle doesn't store the value of the function in the table for each row, it simply stores the description of the defining function as the column definition in the data dictionary"
    I believe that the  actual values derived from the function are stored with each row.
     

    If you dump a table block you will see that the virtual data isn't really stored. The value is, of course, stored in an index along with the ROWID of the corresponding row as Jonathan said.

    An easier way to see it isn't really stored is to modify your example a bit to make the hidden column REALLY big and then see how many rows you can fit into a block:

    CREATE TABLE TEST_FBI_VC1
    (
      OWNER           VARCHAR2(30 BYTE)
    ) create index hkc_test_fbi_vc_ndx1 on test_fbi_vc1(rpad(owner,3000,'X')); INSERT INTO TEST_FBI_VC1 VALUES ('ABC') exec dbms_stats.gather_table_stats('','TEST_FBI_VC1'); SELECT NUM_ROWS, BLOCKS, EMPTY_BLOCKS
    FROM ALL_TABLES
    WHERE TABLE_NAME = 'TEST_FBI_VC1' NUM_ROWS,BLOCKS,EMPTY_BLOCKS 540,5,0

    Hmmm - 540 rows of 3003 bytes doesn't seem like it would fit in only 5 blocks (the initial allocation).

  • Jonathan Lewis
    Jonathan Lewis Member Posts: 10,117 Blue Diamond
    edited Jan 16, 2014 4:04AM
    Hemant K Chitale wrote:
    
    I actually see the avg_row_len increasing -- as if the computed value is stored with the table.
    
    
    
    

    Hemant,

    That's a good point, and worth making.

    It's an example of how any new feature that appears in Oracle has a number of little bits of related code that have not been brought up to date. There's some generic code that calculates avg_row_len as sum(avg_col_len), and doesn't exclude the virtual columns.

    Arguably, of course, it's the correct thing to do since (if I recall correctly) the optimizer actually uses avg_row_len in its volume (bytes) calculations when your SQL includes select * from base_table" - maybe avg_row_len has always meant "length of in-memory image of row" rather than "length of on-disc size of row".

    If you want an example of another anomaly you just have to look at LOBs. If you store an empty_clob() in a column Oracle reports its column size as 86 bytes, even though the on-disc size is 35 bytes (or thereabouts).  Presumably the in-memory size of a LOB locator is the size of a statically declared structure that has a maximum size of 86 bytes.

    (Tip: try experimenting with ANALYZE on a table, then add a virtual column - ANALYZE uses the on-disc size as the row length)

    Regards

    Jonathan Lewis.

This discussion has been closed.