Write here your abstract

1 Server contention

This is the first section: Write here your text

1.1 Disk contention

Copy
onstat -g wai | grep IO
2        8d084d68         0                1    IO Idle                 3lio*        lio vp 0
 3        8d0cc3d8         0                1    IO Idle                 4pio*        pio vp 0
 4        8d0ed3d8         0                1    IO Idle                 5aio*        aio vp 0
 5        8d10e3d8         1f505c0          1    IO Idle                 6msc*        msc vp 0
 6        8d13f3d8         0                1    IO Idle                 7fifo*       fifo vp 0
 48       8d949c08         0                3    IO Idle                 8cpu*        kaio
 49       8d98f2b0         0                3    IO Idle                 9cpu*        kaio
 50       8d98f8c8         0                3    IO Idle                13cpu*        kaio
 66       8dc3f028         0                3    IO Idle                16cpu*        kaio
 90       8e9ca748         0                3    IO Idle                 1cpu*        kaio
 91       8ea000b8         0                3    IO Idle                10cpu*        kaio
 92       8ea00680         0                3    IO Idle                11cpu*        kaio
 93       8ea68028         0                3    IO Idle                12cpu*        kaio
 96       8e9a06b8         0                3    IO Idle                15cpu*        kaio
 97       8e7ec028         0                3    IO Idle                14cpu*        kaio
 1479     dba33568         0                3    IO Idle                17bts*        kaio
 1515     d9816028         0                3    IO Idle                18bts*        kaio
 2936858  369bd78f8        0                3    IO Idle                26jvp*        kaio

1.2 SQL Statements Performancen

Copy
cat << EOF | dbaccess sysmaster -
          SELECT FIRST 25
                 SUBSTR(sql_statement, 0, 500) AS sql_statement,
                 sql_database,
                 COUNT(*) AS num_execs,
                 TRUNC(SUM(sql_runtime),4)     AS totalruntime,
                 TRUNC(MAX(sql_runtime),4)     AS maxruntime,
                 TRUNC(AVG(sql_runtime),4)     AS avgruntime,
                 TRUNC(MIN(sql_runtime),4)     AS minruntime,
                 TRUNC(AVG(sql_actualrows), 1) AS avgrows,
                 TRUNC(SUM(sql_lockwaits ), 1) AS numlockwaits,
                 TRUNC(SUM(sql_lockwttime),4)  AS lockwttime,
                 TRUNC(SUM(sql_numiowaits),4)  AS numiowaits,
                 SUM( sql_pgreads )     AS sql_pgreads,
                 SUM( sql_pgwrites )    AS sql_pgwrites,
                 SUM( sql_bfreads )     AS sql_bfreads,
                 SUM( sql_bfwrites )    AS sql_bfwrites,
                 SUM( sql_lockreq )     AS sql_lockreq,
                 SUM( sql_sortdisk )    AS sql_sortdisk,
                 SUM( sql_sortmem )     AS sql_sortmem
            FROM syssqltrace
           GROUP BY 1, 2
           ORDER BY 4 DESC
EOF

2 Application Design

This is the second section: Write here your text

2.1 Sequential Scans

Check the number of sequential scans performed on each table.

Copy
cat << EOF | dbaccess sysmaster -
select dbsname[1,20], tabname[1,20], sysptntab.partnum, pf_seqscans from sysptntab, systabnames
 where sysptntab.partnum = systabnames.partnum
   and sysptntab.pf_seqscans > 50
order by pf_seqscans desc
EOF

An outsize number of sequential scans in a table may denote an improper and non optimized SQL statements executed by you aplications. Review you applications and check all SQL statements using this tables

2.2 Disk access

Copy
cat << EOF | dbaccess sysmaster -
select FIRST 50 dbsname[1,20], tabname[1,20], sysptntab.partnum, pf_dskreads, pf_bfcread from sysptntab, systabnames
 where sysptntab.partnum = systabnames.partnum
   and sysptntab.pf_dskreads > 50
order by pf_dskreads desc
EOF

2.3 Massive data access

Copy
cat << EOF | dbaccess sysmaster -
select FIRST 50 dbsname[1,20], tabname[1,20], sysptntab.partnum, pf_dskreads, pf_bfcread from sysptntab, systabnames
 where sysptntab.partnum = systabnames.partnum
   and sysptntab.pf_bfcread > 50
order by pf_bfcread desc
EOF

3 Undocumented ONCONFIG Parameters

3.1 OPT_SEEK_FACTOR: Query not using index path

A query was using index path previously and running quickly. After an upgrade the query is doing a sequential scan. Using an index directive the query uses the index and runs much faster than the sequential scan. The index path has a higher estimated cost associated with it than the sequential scan. Also, after an upgrade it could be seen that the optimizer chooses a different index in the newer version of Informix than it did in the older version causing the query to run slower.

ONCONFIG parameter OPT_SEEK_FACTOR

This parameter allows us to set the "weight" of an i/o seek cost. This new costing was added in 11.70.FC3 and higher in the 11.70 family. The range is 0 to 25. The default in version 11.70.xC7 is 6. The default value is pre-11.70.xC7 versions is 10.

Setting it lower causes the seek cost to be lower which lowers the estimated cost of using an index path.

You can revert to the old costing method by setting OPT_SEEK_FACTOR to 0 in the ONCONFIG.

Higher values tend to overestimate the cost of using indexes and so can often cause the optimizer to favor a hash join even with OPTCOMPIND set to zero. If your storage is SSD or other low latency seek storage then OPT_SEEK_FACTOR should be set to zero. That will restore the pre-11.70 optimizer calculations.

3.2 OPTCOMPIND

OPTCOMPIND controls whether the optimizer favors nested loop or hash joins. For an OLTP environment it should be set to zero while the default is 2.

3.3 OPT_GOAL

You should probably not be setting OPT_GOAL to anything other than the default of -1. OPT_GOAL 0 was implemented to make interactive form based applications seem more responsive so that the app could display the first rows quickly when a returning data set includes many many rows. It tends to avoid sorting and prefers using an index on the sort key if available which can make returning the entire data set a bit slower but the first N rows arrive much more quickly. Originally it forced a MERGE JOIN but I believe that the merge join code was removed again in v11.10 (it had been removed in 7.30 and reinstalled in 7.31). This feature was implemented at Bloomberg and for Sears Holding back in the mid-90s when both customers were having problems with interactive apps that appeared slow. Without the MERGE JOIN code it's not as useful. Also it looks like it may be broken.

3.4 SQL_FEAT_CTRL

We also switched this undocumented variable SQL_FEAT_CTRL from default to x9008 and improves so little.

To avoid sub query flattening, set NO_SUBQF=1 from the client application before running the query. Also, you can disable sub query flattening for statements with (Not Exists) in them by setting the onconfig parameter SQL_FEAT_CTRL 0x00008000.

Added a new algorithm for gathering statistics to use sampling which avoids having to traverse the entire btree. We’ve gone to great lengths to make sure we handle skewed data with a proprietory algorithm. That 300% speed jumps to 2000% and best of all, unless the data is skewed, the time it takes to get stats on and index remains fairly constant regardless of the size of the index. That 1M page index will take you about 30s-50s to get stats. Same for that 5M page index. No more waiting hours for update statistics to complete.

What do you have to do to take advantage of this?

onmode -wm SQL_FEAT_CTRL=0

3.5 SQL_DEF_CTRL

We had tested with SQL_DEF_CTRL variable from 080 to 040 on the v11 and that forces the optimizer to use Dynamic hash joints from Nested loops that best performs. But we cant determine what is the best option to try on that variable on v14 to force the optimizer to use nested loops joints.

Flag Feature
0x2 Optimiser vulnerable to poor query response times on incrementing columns
0x80 Enables the optimization of TEMP tables that queries create to store derived tables and materialized view. Internally generated TEMP tables will be created with only a subset of the columns from the view or derived table.
0x400000 table minversion DBA feature