We are planning to run a TPCH database test on informix database using a regular engine and the memory accelerated option (IWA). In the following sections we will follow the steps need to run both tests.

Assming we have setup dbgen utility and we know how to generate TPCH files, lets start with the data load process.

1 Sizing database

Consider to use at least a dbpsace for tables and one for indexes. And for large scales (>1000) use multiple dbspaces for table fragmentation (mainly lineitem).

1.1 Dbspaces

You need to create appropate dbspaces to load tables and indexes. For large databases, you will need to use 16K pages or even use multiple dbspaces to use fragmentation.

1.2 Fragments according scale

There is a maximun number of pages for table or fragment: 16,777,215 pages. So you must adapt the page size according to the scale to avoid exceeding the limit. The next values are for table lineitem (rowsize 146 bytes), it is the biggest table on tpch database.

Table lineitem (rowsize 146 bytes)
TPCH Scale Rows Size 2K pages 16K pages
10 60M 8 GB 3,903,414 488,046
50 300M 40 GB [fragmentation] 2,347,923
100 600M 80 GB [fragmentation] 4,938,623
200 1.2B 160 GB [fragmentation] 9,763,204
1000 6B 800 GB [fragmentation] [fragmentation]

2 Step by step loading

You may create now a dbgen example database and load the data files on it.

If you plan to use a large database (scale > 50), create appropiate dbspaces with 16K pagesize. The default (2K) is too low to allocate large tables.

Also, estimate the initial extent size for tables based on filesize divided by pagesize. $$ \texttt{estimated_extents} = \frac{filesize}{pagesize} $$

Set the environment variables DBDATE=Y4MD- and DBMONEY=.

Copy
export DBDATE=Y4MD-
export DBMONEY=.

2.1 Create tables

Now, create the database under the appropiate dbspace. Notice that for the largest table (lineitem) you may need to use an specific dbspace or even use fragmentation.

Copy
create database tpch in DBSPACE;

-- ==================================================
-- CREATE TABLES
-- ==================================================


create raw table nation (
    n_nationkey integer not null ,
    n_name char(25) not null ,
    n_regionkey integer not null ,
    n_comment varchar(152) 
) lock mode row;

create raw table region (
    r_regionkey integer not null ,
    r_name char(25) not null ,
    r_comment varchar(152) 
) lock mode row;

create raw table part (
    p_partkey integer not null ,
    p_name varchar(55) not null ,
    p_mfgr char(25) not null ,
    p_brand char(10) not null ,
    p_type varchar(25) not null ,
    p_size integer not null ,
    p_container char(10) not null ,
    p_retailprice decimal(15,2) not null ,
    p_comment varchar(23) not null 
) lock mode row;

create raw table supplier (
    s_suppkey integer not null ,
    s_name char(25) not null ,
    s_address varchar(40) not null ,
    s_nationkey integer not null ,
    s_phone char(15) not null ,
    s_acctbal decimal(15,2) not null ,
    s_comment varchar(101) not null 
) lock mode row;

create raw table partsupp (
    ps_partkey integer not null ,
    ps_suppkey integer not null ,
    ps_availqty integer not null ,
    ps_supplycost decimal(15,2) not null ,
    ps_comment varchar(199) not null ) lock mode row;
    create raw table customer (
    c_custkey integer not null ,
    c_name varchar(25) not null ,
    c_address varchar(40) not null ,
    c_nationkey integer not null ,
    c_phone char(15) not null ,
    c_acctbal decimal(15,2) not null ,
    c_mktsegment char(10) not null ,
    c_comment varchar(117) not null 
) lock mode row;

create raw table orders (
    o_orderkey integer not null ,
    o_custkey integer not null ,
    o_orderstatus char(1) not null ,
    o_totalprice decimal(15,2) not null ,
    o_orderdate date not null ,
    o_orderpriority char(15) not null ,
    o_clerk char(15) not null ,
    o_shippriority integer not null ,
    o_comment varchar(79) not null 
) lock mode row;

create raw table lineitem (
    l_orderkey integer not null ,
    l_partkey integer not null ,
    l_suppkey integer not null ,
    l_linenumber integer not null ,
    l_quantity decimal(15,2) not null ,
    l_extendedprice decimal(15,2) not null ,
    l_discount decimal(15,2) not null ,
    l_tax decimal(15,2) not null ,
    l_returnflag char(1) not null ,
    l_linestatus char(1) not null ,
    l_shipdate date not null ,
    l_commitdate date not null ,
    l_receiptdate date not null ,
    l_shipinstruct char(25) not null ,
    l_shipmode char(10) not null ,
    l_comment varchar(44) not null 
) lock mode row;

2.2 Load data

Now, load data into tables.

Note that the path for the load files must be absolute.
Copy
database tpch;

-- ==================================================
-- CREATE EXTERNAL TABLES
-- ==================================================

create external table nation_ext   sameas nation   using ( datafiles("disk:/data/nation.tbl"));
create external table region_ext   sameas region   using ( datafiles("disk:/data/region.tbl"));
create external table part_ext     sameas part     using ( datafiles("disk:/data/part.tbl"));
create external table supplier_ext sameas supplier using ( datafiles("disk:/data/supplier.tbl"));
create external table partsupp_ext sameas partsupp using ( datafiles("disk:/data/partsupp.tbl"));
create external table customer_ext sameas customer using ( datafiles("disk:/data/customer.tbl"));
create external table orders_ext   sameas orders   using ( datafiles("disk:/data/orders.tbl"));
create external table lineitem_ext sameas lineitem using ( datafiles("disk:/data/lineitem.tbl"));

-- ==================================================
-- INSERT DATA FROM EXTERNAL TABLES
-- ==================================================

insert into nation select * from nation_ext;
insert into region select * from region_ext;
insert into supplier select * from supplier_ext;
insert into customer select * from customer_ext;
insert into part select * from part_ext;
insert into partsupp select * from partsupp_ext;
insert into lineitem select * from lineitem_ext;
insert into orders select * from orders_ext;

-- ==================================================
-- MODIFY TABLES FROM RAW TO STANDARD
-- ==================================================

alter table nation type (standard);
alter table region type (standard);
alter table supplier type (standard);
alter table customer type (standard);
alter table part type (standard);
alter table partsupp type (standard);
alter table lineitem type (standard);
alter table orders type (standard);

2.3 Create indexes

According the size of database, you will need to allocate appropiate dbspaces for indexes, specially for lineitem table.

Copy
database tpch;

-- If database is logged and HDR is enabled, lock mode to wait
-- is required to avoid issues about tables blocked
set lock mode to wait ;
set pdqpriority 100;

-- ==================================================
-- CREATE UNIQUE INDEXES
-- ==================================================

create unique index if not exists region_pk on region (r_regionkey) in d_data;
create unique index if not exists nation_pk on nation (n_nationkey) in d_data;
create unique index if not exists supplier_pk on supplier (s_suppkey) in d_data;
create unique index if not exists customer_pk on customer (c_custkey) in d_data;
create unique index if not exists part_pk on part (p_partkey) in d_data;
create unique index if not exists partsupp_pk on partsupp (ps_partkey, ps_suppkey) in d_data;
create unique index if not exists orders_pk on orders (o_orderkey) in d_data;
create unique index if not exists lineitem_pk on lineitem (l_orderkey, l_linenumber) in d_data;

-- ==================================================
-- CREATE INDEXES
-- ==================================================

create index if not exists nation_fk_region on nation (n_regionkey) in d_data;
create index if not exists supplier_fk_nation on supplier (s_nationkey) in d_data;
create index if not exists partsupp_fk_part on partsupp (ps_partkey) in d_data;
create index if not exists partsupp_fk_supplier on partsupp (ps_suppkey) in d_data;
create index if not exists customer_fk_nation on customer (c_nationkey) in d_data;
create index if not exists orders_fk_customer on orders (o_custkey) in d_data;
create index if not exists i_orders_orderdate on orders (o_orderdate) in d_data;
create index if not exists lineitem_fk_orders on lineitem (l_orderkey) in d_data;
create index if not exists lineitem_fk_part on lineitem (l_partkey) in d_data;
create index if not exists lineitem_fk_supplier on lineitem (l_suppkey) in d_data;
create index if not exists i_lineitem_shipdate on lineitem (l_shipdate, l_discount, l_quantity) in d_data;

-- ==================================================
-- ADD PRIMARY KEY CONSTRAINTS
-- ==================================================

alter table region add constraint (primary key (r_regionkey));
alter table nation add constraint (primary key (n_nationkey));
alter table supplier add constraint (primary key (s_suppkey));
alter table customer add constraint (primary key (c_custkey));
alter table part add constraint (primary key (p_partkey));
alter table partsupp add constraint (primary key (ps_partkey, ps_suppkey)) ;
alter table lineitem add constraint (primary key (l_orderkey, l_linenumber));
alter table orders add constraint (primary key (o_orderkey)) ;

-- ==================================================
-- ADD FOREIGN KEY CONSTRAINTS
-- ==================================================

alter table nation add constraint (foreign key (n_regionkey) references region novalidate) ;
alter table supplier add constraint (foreign key (s_nationkey) references nation novalidate) ;
alter table partsupp add constraint (foreign key (ps_partkey) references part novalidate);
alter table partsupp add constraint (foreign key (ps_suppkey) references supplier novalidate);
alter table customer add constraint (foreign key (c_nationkey) references nation novalidate);
alter table orders add constraint (foreign key (o_custkey) references customer novalidate) ;
alter table lineitem add constraint (foreign key (l_orderkey) references orders novalidate) ;
alter table lineitem add constraint (foreign key (l_partkey) references part novalidate);
alter table lineitem add constraint (foreign key (l_suppkey) references supplier novalidate);

2.4 Update statistics

Use the UPDATE STATISTICS statement to update system catalog information that the query optimizer uses for operations on objects in the local database.

Copy
database tpch;
update statistics;

2.5 Perform level 0 backup

Finally you must perform a level-0 backup to turn off read-only access on the express-mode loaded tables(s). You can run a fake backup, if you prefer not to run a true level-0 backup at the time:

Copy
$ ontape -s -F -t /dev/null

3 Performance test time

Loading data in single dbspace, non fragmented tables:

Table loaded SF=1 SF=10 SF=100 (mm:ss) SF=1000
SSD NVME SSD NVME SSD NVME NVME (Fragmented) SSD NVME
nation . . . . 00:00 00:00 00:00 . .
region . . . . 00:00 00:00 00:00 . .
supplier . . . . 00:08 00:05 00:11 . .
customer . . . . 02:11 01:00 01:54 . .
part . . . . 01:44 01:02 02:18 . .
partsupp . . . . 04:39 03:04 08:01 . .
lineitem . . . . 59:08 56:23 17:02 . .
orders . . . . 09:09 09:27 . . .
total loading . . . . 77:07 72:14 31:32 . .
Index creation . . . . 180m56 82:05 04:24 . .

Diferences between ssd and nvme technologies in load time are not impressive. This is produced because CPU power has reached their limit. Loadin gprocess is a single threaded process and in both technologies CPU core raises to 100% utilization.

4 Troubleshooting

4.1 Informix ISAM error 136: no more extents

4.1.1 Problem

Informix can only allocate a maximum of 16,777,215 disk pages per table partition or fragment. It should also be noted that this is independent of the dbspace configured page size. Also, IDS can only track approximately 200 extents (logical grouping of disk pages) per table partition or fragment. The most likely root cause will be that one or both these values have been realized.

4.1.2 Cause

During load, a large table may take more than the physical limit of extents (16,777,215) if you have not defined the initial extent size, cause database don't know before loading it's size.

4.1.3 Solution

Before loading, estimate the extent size of large tables. But if table is so large, you must increase the dbspace pagesize (an extent size has a limit).

For example:

You want to create a dbspace of 16K pagesize with an initial 100 GB chunk (100*(1024*1024*1024)). As size of a chunk is expressed in K, you should use (100*(1024*1024)) = 104857600.

Copy
$ onspaces -c -d d_data -k 16 -p /INFORMIXDEV/d_data_01 -o 0 -s 104857600

This will generate a dbspace of 6553600 pages as $$ \frac{104857600 * 1024}{16 * 1024} = 6553600 $$

Notice that size is expressed in K bytes, so we need to divide by 1024 or desired size of 100GB.

To add a second 100GB chunk to the dbspace, use

Copy
$ onspaces -a d_data  -p /INFORMIXDEV/d_data_02 -o 0 -s 104857600

4.2 Running SQL but seeing errors 215 and 197

4.2.1 Problem

You try to run an sql on a table or database but see an error like this:

Copy
215: Cannot open file for table (test).

197: ISAM error: Cannot open a recently appended logged partition for writing.

4.2.2 Cause

A High Performance Loader (HPL), onpladm, or external table load job using express-mode was run on the table mentioned in error 215. Express-mode loads use light appends, which bypass the buffer pool. Light appends eliminate the overhead associated with buffer management but do not log the data. Only read-only access is allowed to the tables until a level-0 archive is performed.

4.2.3 Resolving the problem

After a load like this remember to execute a level-0 backup (can be a fake backup):

Copy
ontape -s -F -t /dev/null