This document describes a test of TPCH benchmark at low scales (1, 100) using Informix on single NUC computer.
You can read about TPCH benchmark:
1 Informix setup
Let's configure Informix database instance for test.
1.1 Initialize database engine
-
Create the the links for the data files. Login as root and perform the device setup.
In our example, /data is a filsesystem where we will create the database dbspace files.
Copy
mkdir /data/IFMX-CHUNKS chown informix:informix /data/IFMX-CHUNKS touch /data/IFMX-CHUNKS/rootdbs touch /data/IFMX-CHUNKS/d_plog touch /data/IFMX-CHUNKS/d_llog touch /data/IFMX-CHUNKS/t_tmp1 touch /data/IFMX-CHUNKS/t_tmp2 touch /data/IFMX-CHUNKS/t_tmp3 touch /data/IFMX-CHUNKS/t_tmp4 touch /data/IFMX-CHUNKS/t_tmp5 touch /data/IFMX-CHUNKS/t_tmp6 touch /data/IFMX-CHUNKS/d_data_0 touch /data/IFMX-CHUNKS/i_data_0 chmod 775 /data/IFMX-CHUNKS chown informix:informix /data/IFMX-CHUNKS chmod 660 /data/IFMX-CHUNKS/* chown informix:informix /data/IFMX-CHUNKS/*
-
Ensure the onconfig variable ROOTPATH points to the appropriate file. Verify it's correctly set:
Copy
$ onstat -c | grep ^ROOTPATH
ROOTPATH /data/IFMX-CHUNKS/rootdbs
-
Set onconfig variable LOGSIZE to at least 10000 (10Mb). Verify it's correctly set:
Copy
$ onstat -c | grep ^LOGSIZE
LOGSIZE 10000
-
Initialize engine
Copy
$ oninit -iv
This action will initialize IBM Informix Dynamic Server; any existing IBM Informix Dynamic Server databases will NOT be accessible - Do you wish to continue (y/n)? y Reading configuration file '/home/informix/etc/onconfig'...succeeded Creating /INFORMIXTMP/.infxdirs...succeeded Allocating and attaching to shared memory...succeeded Creating resident pool 274958 kbytes...succeeded Creating infos file "/home/informix/etc/.infos.nuc00"...succeeded Linking conf file "/home/informix/etc/.conf.nuc00"...succeeded Initializing rhead structure...rhlock_t 262144 (8192K)... rlock_t (265625K)... Writing to infos file...succeeded Initialization of Encryption...succeeded Initializing ASF...succeeded Initializing Dictionary Cache and SPL Routine Cache...succeeded Initializing encryption-at-rest if necessary...succeeded Bringing up ADM VP...succeeded ...
-
Create dbspaces
Copy
onspaces -c -P d_plog -p /data/IFMX-CHUNKS/d_plog -o 0 -s 8000000 onspaces -c -d d_llog -p /data/IFMX-CHUNKS/d_llog -o 0 -s 2000000 onspaces -c -t -d t_tmp1 -p /data/IFMX-CHUNKS/t_tmp1 -o 0 -s 20000000 -k 16 onspaces -c -t -d t_tmp2 -p /data/IFMX-CHUNKS/t_tmp2 -o 0 -s 20000000 -k 16 onspaces -c -t -d t_tmp3 -p /data/IFMX-CHUNKS/t_tmp3 -o 0 -s 20000000 -k 16 onspaces -c -t -d t_tmp4 -p /data/IFMX-CHUNKS/t_tmp4 -o 0 -s 20000000 -k 16 onspaces -c -t -d t_tmp5 -p /data/IFMX-CHUNKS/t_tmp5 -o 0 -s 20000000 -k 16 onspaces -c -t -d t_tmp6 -p /data/IFMX-CHUNKS/t_tmp6 -o 0 -s 20000000 -k 16 onspaces -c -d d_data -p /data/IFMX-CHUNKS/d_data_0 -o 0 -s 200000000 -k 16 onspaces -c -d i_data -p /data/IFMX-CHUNKS/i_data_0 -o 0 -s 100000000 -k 16
-
Create additional logical logs
Copy
onparams -a -d d_llog -s 100000 onparams -a -d d_llog -s 100000 onparams -a -d d_llog -s 100000 onparams -a -d d_llog -s 100000 onparams -a -d d_llog -s 100000 onparams -a -d d_llog -s 100000 onparams -a -d d_llog -s 100000
-
Perform a Level 0 backup
Copy
ontape -s -L 0 -t /dev/null
-
Stop admin tasks
Copy
touch $INFORMIXDIR/etc/sysadmin/stop
1.2 Onconfig settings
Check the following paramters and adjust if necessary.
Parameter | Value | Description |
---|---|---|
Dbspaces | ||
LTAPEDEV | /dev/null | Disable logical log backup |
Logs | ||
PHYSBUFF | 2048 | Size of physical buffer |
PHYSFILE | 8000000 | Size of physical log (set initial size o 40000, the create later using a specific dbspace) |
Virtual processors | ||
VPCLASS | cpu,num=4,noage | Number of processors |
VP_MEMORY_CACHE_KB | 32000,DYNAMIC | private memory cache for each CPU virtual processor and tenant virtual processor. |
SHMVIRTSIZE | 8000000 | Initial size (10GB) of a virtual shared-memory segment expressed in KB. Notice that DS_TOTAL_MEMORY is a logical subset of SHMVIRTSIZE. |
AIO and Cleaner-Related Configuration | ||
CLEANERS | 32 | Specify the number of page-cleaner threads available. |
DIRECT_IO | 1 | As we are using cooked files, enable KAIO on files by setting DIRECT_IO. |
PDQ priority | ||
MAX_PDQPRIORITY | 100 | Sets the percentage of the user-requested PDQ resources actually allocated to the query. 100 uses all available resources for processing queries in parallel. |
DS_MAX_QUERIES | 4 | The the maximum number of parallel database queries (PDQ) that can run concurrently. This acts as divisor of grant memory manager. The quantum memory isDS_TOTAL_MEMORY/DS_MAX_QUERIES |
DS_TOTAL_MEMORY | 6000000 | The amount of memory available for PDQ queries (KB). |
DS_NONPDQ_QUERY_MEM | 100000 | The amount of memory that is available for a query that is not a Parallel Database Query (up to 25% DS_TOTAL_MEMORY) |
PSORT_NPROCS | 4 | Enable the database server to improve the performance of the parallel-process sorting package by allocating more threads for sorting |
OPTCOMPIND | 2 | Nested-loop joins are not necessarily preferred. The optimizer bases its decision purely on costs, regardless of transaction isolation mode. |
Buffers | ||
BUFFERPOOL | 2K | size=2K,buffers=200000,lrus=8,lru_min_dirty=50,lru_max_dirty=60 |
BUFFERPOOL | 16K | size=16K,buffers=1200000,lrus=8,lru_min_dirty=50,lru_max_dirty=60.5 |
The PDQPRIORITY has been set to 100 before SQL statements.
set PDQPRIORITY 100;
1.3 Create logical logs and temp spaces
onspaces -c -d d_llog -p /data/IFMX-CHUNKS/d_llog -o 0 -s 2000000 onspaces -c -t -d t_tmp1 -p /data/IFMX-CHUNKS/t_tmp1 -o 0 -s 20000000 -k 16 onspaces -c -t -d t_tmp2 -p /data/IFMX-CHUNKS/t_tmp2 -o 0 -s 20000000 -k 16 onspaces -c -t -d t_tmp3 -p /data/IFMX-CHUNKS/t_tmp3 -o 0 -s 20000000 -k 16 onspaces -c -t -d t_tmp4 -p /data/IFMX-CHUNKS/t_tmp4 -o 0 -s 20000000 -k 16 onspaces -c -t -d t_tmp5 -p /data/IFMX-CHUNKS/t_tmp5 -o 0 -s 20000000 -k 16 onspaces -c -t -d t_tmp6 -p /data/IFMX-CHUNKS/t_tmp6 -o 0 -s 20000000 -k 16
2 Sizing dbspaces
Before running tests, we should prepare the database instance with appropriate dbspaces to hold TPCH database.
You can get a simple estimation of table size by multiplying the number of expected rows by it's row size. Row size can be determined by using:
SELECT rowsize FROM systables WHERE tabname = "lineitem";
146
To determine the data pages need to store a table we can use the following formula: $$ \texttt{data_pages} = \frac{rows}{trunc(pagesize/(rowsize + 4))} $$ so we have divisor of
- 2048/(146+4) = 13.6 for 2K pages
- 4096/(146+4) = 27.3 for 4K pages
- 16384/(146+4) = 109.2 for 16K pages
The maximum number of pages per tblspace is 16,777,215. So this limites the maximum number of rows for tblspace. If a table exceeds this limit it must be fragmented so it's make of multiple tblspaces.
Using TPCH sample we get the following metrics:
TPCH Scale |
Rows | Row size * rows | Bytes | GB | 2K pages div=13.6 |
4K pages div=27.3 |
16K pages div=109.2 |
Requires Fragments |
---|---|---|---|---|---|---|---|---|
100 | 600M | 146 * 600,000,000 | 87,600,000,000 | 81 | 44,117,647 | 21,978,021 | 5,494,505 | 0 |
200 | 1.2B | 146 * 1,200,000,000 | 175,200,000,000 | 163 | 88,235,294 | 43,956,043 | 10,989,010 | 0 |
500 | 1.2B | 146 * 3,000,000,000 | 438,000,000,000 | 407 | 213,867,187 | 109,890,109 | 26,733,398 | 1.59 |
1000 | 6B | 146 * 6,000,000,000 | 876,000,000,000 | 815 | 441,176,470 | 54,945,054 | 219,780,219 | 3.27 |
So we can deduce:
- We can place the 600M or even 1.2B rows in a single dbspace but only using 16K pagesize.
Using 2K we will exceed the maximum number of pages per table of fragment (
16,777,215
). - We can not place the 6B rows in a single dbspace for two causes.
- 6B rows is gretater than the 4B rows limit per fragment
- Even at 16K pagesize we exceed the maximum number of extenters per tblspace of fragment.
2.1 Having VARCHARS
The estimated pages for a given rowsize does not take in account the use of varchars. If a table constains varchars and they are not fully filled, the row size can be less and the number of pages for all table may be significantly less.
The fact table lineitem
contains a field l_comment
that is varchar(44)
.
In our test, the expected number of pages for lineitem at SF 100 and 4K page size is 21,978,021.
But the read need is 16.773.053. It's only 2081 before the max limit of 16,775,134 pages per
tblspace.
3 DBgen setup
We need to have dbgen utility (compiled for informix) ready to generate data files to load. We also need to run the generation in a filesystem with suffcient capacity to store the size of generated files.
$ cd /data/TPCH (or any appropriate directory) $ git clone https://github.com/electrum/tpch-dbgen.git
Cloning into 'tpch-dbgen'...
remote: Enumerating objects: 149, done.
remote: Total 149 (delta 0), reused 0 (delta 0), pack-reused 149
Receiving objects: 100% (149/149), 214.31 KiB | 0 bytes/s, done.
Resolving deltas: 100% (34/34), done.
3.1 Compile dbgen
In the downloaded directory (tpch-dbgen), edit the file makefile.suite
and set
the following variables to the appropriate vaules:
-
Copy
$ cd tpch-dbgen
-
Edit makefile.suite and change the following variables, the save it.
Copy
CC=gcc DATABASE=INFORMIX MACHINE=LINUX WORKLOAD=TPCH
-
From command line run the make utility:
Copy
$ make -f makefile.suite
gcc -g -DDBNAME=\"dss\" -DMAC -DINFORMIX -DTPCH -DRNG_TEST -D_FILE_OFFSET_BITS=64 -c -o build.o build.c gcc -g -DDBNAME=\"dss\" -DMAC -DINFORMIX -DTPCH -DRNG_TEST -D_FILE_OFFSET_BITS=64 -c -o driver.o driver.c ...
-
Copy dbgen and dists.dss to the parent directory where we will run the generation.
Copy
$ cp dbgen dists.dss ../
-
Change to parent directory.
Copy
$ cd .. $ ls -l
total 124 -rwxrwxr-x 1 informix informix 106560 Nov 19 16:55 dbgen -rw-rw-r-- 1 informix informix 11815 Nov 19 16:50 dists.dss drwxrwxr-x 9 informix informix 4096 Nov 19 16:49 tpch-dbgen
3.2 Run dbgen
Now test dbgen is working. To do that simply run the generation for scale 1.
We will store generated files in the appropriate directory (in our sample a subdirectory named data)
$ mkdir data $ export DSS_PATH=data $ ./dbgen -s 1
TPC-H Population Generator (Version 2.14.0)
Copyright Transaction Processing Performance Council 1994 - 2010
Now we can see the generated files. We are ready to run tests.
$ ls -l data
-rw-rw-r-- 1 informix informix 24346144 Nov 19 16:55 customer.tbl
-rwxrwxr-x 1 informix informix 106560 Nov 19 16:55 dbgen
-rw-rw-r-- 1 informix informix 11815 Nov 19 16:50 dists.dss
-rw-rw-r-- 1 informix informix 759863287 Nov 19 16:55 lineitem.tbl
-rw-rw-r-- 1 informix informix 2224 Nov 19 16:55 nation.tbl
-rw-rw-r-- 1 informix informix 171952161 Nov 19 16:55 orders.tbl
-rw-rw-r-- 1 informix informix 118984616 Nov 19 16:55 partsupp.tbl
-rw-rw-r-- 1 informix informix 24135125 Nov 19 16:55 part.tbl
-rw-rw-r-- 1 informix informix 389 Nov 19 16:55 region.tbl
-rw-rw-r-- 1 informix informix 1409184 Nov 19 16:55 supplier.tbl
drwxrwxr-x 9 informix informix 4096 Nov 19 16:49 tpch-dbgen
3.3 Data generation time
Times of dbgen for different sizes.
SF | Time |
---|---|
1 | 00:15 |
10 | 02:03 |
100 | 20:11 |
1000 | ? |
3.4 Quick dbgen
To quickly generate TPCH scale 10 in a specific directory run:
export DSS_PATH=`pwd`/data10 mkdir $DSS_PATH ./dbgen -f -s 10
4 Creating dbspaces
According previous metrics, we can run without fragmentation up to a scale factor 200 using 16K pages.
4.1 Creating dbspaces for (SF=100)
We choose a 16K page size to match VMEe best block size. It will also be the preferred size as we scale test up to greater sizes.
-
Create 200GB, 16K dbspace for data
Copy
$ onspaces -c -d d_data -p /INFORMIXDEV/d_data_0 -o 0 -s 200000000 -k 16
-
Create 100GB, 16K dbspace for indexes
Copy
$ onspaces -c -d i_data -p /INFORMIXDEV/i_data_0 -o 0 -s 100000000 -k 16
-
Create temporary dbspaces
Copy
$ touch /INFORMIXDEV/t_tmp1 /INFORMIXDEV/t_tmp2 /INFORMIXDEV/t_tmp3 /INFORMIXDEV/t_tmp4 /INFORMIXDEV/t_tmp5 /INFORMIXDEV/t_tmp6 # su root # chmod 660 /INFORMIXDEV/t_tmp[1-6] # chown informix:informix /INFORMIXDEV/t_tmp[1-6] # exit $ onspaces -c -t -d t_tmp1 -p /INFORMIXDEV/t_tmp1 -o 0 -s 20000000 $ onspaces -c -t -d t_tmp2 -p /INFORMIXDEV/t_tmp2 -o 0 -s 20000000 $ onspaces -c -t -d t_tmp3 -p /INFORMIXDEV/t_tmp3 -o 0 -s 20000000 $ onspaces -c -t -d t_tmp4 -p /INFORMIXDEV/t_tmp4 -o 0 -s 20000000 $ onspaces -c -t -d t_tmp5 -p /INFORMIXDEV/t_tmp5 -o 0 -s 20000000 $ onspaces -c -t -d t_tmp6 -p /INFORMIXDEV/t_tmp6 -o 0 -s 20000000
-
Set onconfig parameter DBSPACETEMP and restart database to take effect.
Copy
DBSPACETEMP t_tmp1,t_tmp2,t_tmp3,t_tmp4,t_tmp5,t_tmp6
-
Generate a fake level 0 archive to enable the dbspaces
Copy
$ ontape -s
Archive to tape device '/dev/null' is complete. Program over.
5 Data generation and loading
The following tables resume the data generation and load time at different scales on a single NUC computer.
5.1 Load and index time
Times for data import and totals for load and full indexing using PDQPRIORITY=100
Table | SF=10 | SF=20 | SF=100 | SF=1000 | ||||||||
---|---|---|---|---|---|---|---|---|---|---|---|---|
Rows | Size GB |
Time | Rows | Size GB |
Time | Rows | Size GB |
Time | Rows | Size GB |
Time | |
region | 5 | 0 | 00:00 | 5 | 0 | 00:00 | 1 | 0 | 00:00 | . | 0 | . |
nation | 25 | 0 | 00:00 | 25 | 0 | 00:00 | 1 | 0 | 00:00 | . | 0 | . |
supplier | 0.1M | 0.01 | 00:00 | 0.2M | 0.01 | 00:00 | 1M | 0.14 | 00:03 | . | 0 | . |
customer | 1.5M | 0.23 | 00:04 | 3M | 0.46 | 00:08 | 15M | 2.3 | 00:42 | . | 0 | . |
part | 2M | 0.26 | 00:06 | 4M | 0.52 | 00:10 | 20M | 2.6 | 00:49 | . | 0 | . |
partsupp | 8M | 1.1 | 00:18 | 16M | 2.2 | 00:38 | 80M | 11 | 03:10 | . | 0 | . |
orders | 15M | 1.5 | 00:37 | 30M | 3 | 01:17 | 150M | 15 | 06:15 | . | 0 | . |
lineitem | 60M | 7.6 | 03:42 | 120M | 15.2 | 08:23 | 600M | 64 | 32:56 | . | 0 | . |
Total table load | 00:04:47 | .. | 00:48:56 | . | ||||||||
Total Indexing | 00:02:32 | .. | 00:32:39 | . |
To review pages loaded, connect to database and run:
select tabname[1,22], npused::int from systables where tabid > 99 and tabtype="T" order by 2
Looking at SF 10 lineitem load, we can observe that Informix loads 60M rows in 3 minutes and 42 seconds. This is a rate of 270K rows / second. For SF = 100 we have 600M rows loaded in 32 minutes and 52 seconds. This gives a load rate of 300K rows / second.
5.2 Commit performance
As we are using the compute in single user mode, we can perfecly monitor it's load speed and commit speed.
The onstat -g ckp
command will let us monitor buffer flush activity. Looking at their number we can see how
fast data is commited to disk.
Force all data in buffers to be flushed to disk by using onmode -c
. This operation may take a few seconds
as many buffers contain read data and need to be commited.
$ onmode -c
Run the command after load is completed.
$ onstat -g ckp
IBM Informix Dynamic Server Version 12.10.FC12AEE -- On-Line -- Up 03:54:08 -- 28194512 Kbytes
AUTO_CKPTS=On RTO_SERVER_RESTART=Off
Critical Sections Physical Log Logical Log
Clock Total Flush Block # Ckpt Wait Long # Dirty Dskflu Total Avg Total Avg
Interval Time Trigger LSN Time Time Time Waits Time Time Time Buffers /Sec Pages /Sec Pages /Sec
88 21:46:17 CKPTINTVL 6:0x342e084 0.1 0.0 0.0 0 0.0 0.0 0.0 132 132 22 0 2 0
89 21:48:48 Alt Tabtype 6:0x34300bc 0.5 0.5 0.0 1 0.0 0.0 0.0 1322 1322 9556 63 194 1
90 21:48:49 *Backup 6:0x350c018 0.9 0.0 0.0 0 0.0 0.0 0.0 21 21 138 69 220 110
91 21:48:50 Backup 6:0x350e2d8 0.1 0.0 0.0 0 0.0 0.0 0.0 0 0 0 0 2 2
92 21:56:03 Plog 6:0x3526458 137.4 137.2 0.0 3 0.0 0.2 0.2 310971 2267 223 0 24 0
93 22:00:51 Plog 6:0x352d128 288.4 287.7 0.0 2 0.0 0.6 0.6 610756 2122 682 4 7 0
94 22:03:14 CKPTINTVL 6:0x3549018 114.3 114.2 0.0 0 0.0 0.0 0.0 270042 2365 498 1 28 0
95 22:07:47 Plog 6:0x354b7e8 157.3 157.3 0.0 2 0.0 0.0 0.0 306642 1949 437 1 3 0
96 22:11:53 CKPTINTVL 6:0x3554018 88.8 88.8 0.0 0 0.0 0.0 0.0 132006 1486 428 1 8 0
97 22:16:08 Plog 6:0x3557208 165.5 165.3 0.0 5 0.0 0.2 0.2 327657 1982 436 2 3 0
98 22:19:28 CKPTINTVL 6:0x355d018 49.6 49.6 0.0 0 0.0 0.0 0.0 83022 1674 452 1 6 0
99 22:23:25 Plog 6:0x356019c 127.7 127.5 0.0 5 0.0 0.2 0.2 297174 2331 443 2 3 0
100 22:27:17 CKPTINTVL 6:0x3572018 42.3 42.2 0.0 0 0.0 0.0 0.0 93918 2223 540 1 18 0
101 22:27:18 *Admin 6:0x3574018 0.7 0.0 0.0 0 0.0 0.0 0.0 1 1 45 1 2 0
102 22:28:00 *Admin 6:0x3576044 0.0 0.0 0.0 0 0.0 0.0 0.0 0 0 0 0 2 0
103 22:38:16 CKPTINTVL 6:0x3578050 0.0 0.0 0.0 0 0.0 0.0 0.0 1 1 7 0 2 0
104 22:53:16 CKPTINTVL 6:0x357a018 0.0 0.0 0.0 0 0.0 0.0 0.0 1 1 7 0 2 0
105 23:08:16 CKPTINTVL 6:0x357c018 0.0 0.0 0.0 0 0.0 0.0 0.0 1 1 7 0 2 0
106 23:23:17 CKPTINTVL 6:0x357e018 0.0 0.0 0.0 0 0.0 0.0 0.0 1 1 7 0 2 0
107 23:38:17 CKPTINTVL 6:0x3580018 0.0 0.0 0.0 0 0.0 0.0 0.0 1 1 7 0 2 0
Max Plog Max Llog Max Dskflush Avg Dskflush Avg Dirty Blocked
pages/sec pages/sec Time pages/sec pages/sec Time
10240 1280 288 961 437 0
6 Grid setup
6.1 Configure enterprise replication
6.1.1 Setup environment and trusted relationships
To create an ER domain, all non-root hosts integrated, should be able to connect to each other in implicit connection. Edit $INFORMIXDIR/etc/sqlhosts file in all hosts and add group and host identifiers to all other hosts in domain.
g_nuc00 group - - i=170 ol_nuc00 onsoctcp nuc00 9088 g=g_nuc00 g_nuc01 group - - i=171 ol_nuc01 onsoctcp nuc01 9088 g=g_nuc01 g_nuc02 group - - i=172 ol_nuc02 onsoctcp nuc02 9088 g=g_nuc02 g_nuc03 group - - i=173 ol_nuc03 onsoctcp nuc03 9088 g=g_nuc03 g_nuc04 group - - i=174 ol_nuc04 onsoctcp nuc04 9088 g=g_nuc04 g_nuc05 group - - i=175 ol_nuc05 onsoctcp nuc05 9088 g=g_nuc05 g_nuc06 group - - i=176 ol_nuc06 onsoctcp nuc06 9088 g=g_nuc06 g_nuc07 group - - i=177 ol_nuc07 onsoctcp nuc07 9088 g=g_nuc07 g_nuc08 group - - i=178 ol_nuc08 onsoctcp nuc08 9088 g=g_nuc08 g_nuc09 group - - i=179 ol_nuc09 onsoctcp nuc09 9088 g=g_nuc09 g_nuc10 group - - i=180 ol_nuc10 onsoctcp nuc10 9088 g=g_nuc10
Group names and number id should be defined equally in all informix servers belonging to ER domain.
Allow trusted context between all hosts by editing /etc/hosts.equiv and add trusting relationship:
nuc00 nuc01 nuc02 nuc03 nuc04 nuc05 nuc06 nuc07 nuc08 nuc09 nuc10
After this, you should be able to connect to any informix server in domain, and try to connect as informix to any other server without providing password.
6.1.2 Configure smartblobspaces and filesystem folders for ER
You need to follow next steps in all servers in your ER domain. First, ER needs two folders to store ATS and RIS logs so you need to create it in all hosts:
mkdir -p $INFORMIXDIR/cdr/ats $INFORMIXDIR/cdr/ris
ER requires at least two smartblobspaces to be setted up, to be able to initilize. This sbspaces are used to queue ER operations before all servers in domain acknowledge operations are done. This is the reason why this spaces should be very large to acommodate replication operations with a huge number of rows. Create two smartblobspaces by issuing this commands:
touch /data/IFMX-CHUNKS/s_qdata touch /data/IFMX-CHUNKS/s_sbsp chmod 660 /data/IFMX-CHUNKS/* chown informix:informix /data/IFMX-CHUNKS/* onspaces -c -S s_sbsp -p /data/IFMX-CHUNKS/s_sbsp -o 0 -s 10000000 onspaces -c -S s_qdata -p /data/IFMX-CHUNKS/s_qdata -o 0 -s 10000000
Edit $INFORMIXDIR/etc/onconfig and set up parameter values with this two created sbspaces:
SBSPACENAME s_sbsp CDR_QDATA_SBSPACE s_qdata
And restart informix server to allow this new parameters to work.
6.1.3 Define ER domain
You need to initialize ER domain for first tine. In our example, domain initiator will be nuc00, so connect as informix to nuc_00 and create new domain:
cdr define server --connect ol_nuc00 --init g_nuc00 --ats=/home/informix/cdr/ats --ris=/home/informix/cdr/ris
Then, you need to connect to each of the other hosts pertaining to domain, and attach it to domain sincronizing master domain data from g_nuc00:
At nuc01 execute:
cdr define server --connect ol_nuc01 --init g_nuc01 --sync g_nuc00 --ats=/home/informix/cdr/ats --ris=/home/informix/cdr/ris
At nuc02 execute:
cdr define server --connect ol_nuc02 --init g_nuc02 --sync g_nuc00 --ats=/home/informix/cdr/ats --ris=/home/informix/cdr/ris
At nuc03 execute:
cdr define server --connect ol_nuc03 --init g_nuc03 --sync g_nuc00 --ats=/home/informix/cdr/ats --ris=/home/informix/cdr/ris
At nuc04 execute:
cdr define server --connect ol_nuc04 --init g_nuc04 --sync g_nuc00 --ats=/home/informix/cdr/ats --ris=/home/informix/cdr/ris
At nuc05 execute:
cdr define server --connect ol_nuc05 --init g_nuc05 --sync g_nuc00 --ats=/home/informix/cdr/ats --ris=/home/informix/cdr/ris
At nuc06 execute:
cdr define server --connect ol_nuc06 --init g_nuc06 --sync g_nuc00 --ats=/home/informix/cdr/ats --ris=/home/informix/cdr/ris
At nuc07 execute:
cdr define server --connect ol_nuc07 --init g_nuc07 --sync g_nuc00 --ats=/home/informix/cdr/ats --ris=/home/informix/cdr/ris
At nuc08 execute:
cdr define server --connect ol_nuc08 --init g_nuc08 --sync g_nuc00 --ats=/home/informix/cdr/ats --ris=/home/informix/cdr/ris
At nuc09 execute:
cdr define server --connect ol_nuc09 --init g_nuc09 --sync g_nuc00 --ats=/home/informix/cdr/ats --ris=/home/informix/cdr/ris
At nuc10 execute:
cdr define server --connect ol_nuc10 --init g_nuc10 --sync g_nuc00 --ats=/home/informix/cdr/ats --ris=/home/informix/cdr/ris
When finished, you'll be able to see all your hosts pertaining to ER domain by executing "cdr list server" command:
$ cdr list server
SERVER ID STATE STATUS QUEUE CONNECTION CHANGED
-----------------------------------------------------------------------
g_nuc00 170 Active Connected 0 Nov 30 14:21:17
g_nuc01 171 Active Connected 0 Nov 30 14:21:17
g_nuc02 172 Active Connected 0 Nov 30 14:21:17
g_nuc03 173 Active Connected 0 Nov 30 14:21:17
g_nuc04 174 Active Connected 0 Nov 30 14:21:17
g_nuc05 175 Active Connected 0 Nov 30 14:21:17
g_nuc06 176 Active Connected 0 Nov 30 14:21:17
g_nuc07 177 Active Connected 0 Nov 30 14:21:17
g_nuc08 178 Active Connected 0 Nov 30 14:23:23
g_nuc09 179 Active Connected 0 Nov 30 14:21:17
g_nuc10 180 Active Local 0
6.1.4 Create Informix Grid to create database schemas
Create an Informix grid to create database schemas and allows to reproduce SQL operations in all servers in ER domain. We create two grids, first with all servers and second only with datanode servers (excluding nuc10 coordinator):
Connect to nuc10 and execute the commands:
[informix@nuc10 ~]$ cdr define grid grid_all --all [informix@nuc10 ~]$ cdr define grid grid_nuc g_nuc00 g_nuc01 g_nuc02 g_nuc03 g_nuc04 g_nuc05 g_nuc06 g_nuc07 g_nuc08 g_nuc09 [informix@nuc10 ~]$ cdr list grid
Grid Node User
------------------------ ------------------------ ------------------------
grid_all g_nuc00
g_nuc01
g_nuc02
g_nuc03
g_nuc04
g_nuc05
g_nuc06
g_nuc07
g_nuc08
g_nuc09
g_nuc10
grid_nuc g_nuc00
g_nuc01
g_nuc02
g_nuc03
g_nuc04
g_nuc05
g_nuc06
g_nuc07
g_nuc08
g_nuc09
Next we need to configure grid security setting which nodes and users are able to perform grid operations:
cdr enable grid --grid grid_all --node g_nuc10 cdr enable grid --grid grid_all --user informix
Finally, we perform a grid SQL operation in all servers to increase number of logical logs by adding 20 new logical logs:
database sysadmin; execute function ifx_grid_function('grid_all','task("modify chunk extendable", "3")'); -- create 20 new logical logs in d_llog execute function ifx_grid_function('grid_all','task ("add log","d_llog","100000",30)');
6.2 Create ER replicated dimension tables using grid
In this section we will setup a 10 node grid, using an additional node as coordinator.
Create database and common dimension tables using informix grid capabilities calling ifx_grid_connect(<gridName>, <tag>, <er_enable>) procedure
- The tag and er_enable flags are optional
- The tag can be used to make it easier to monitor the success/failure of grid operations
- er_enable(0/1) enables or disables the creation of a replicate and replicate set AND starting replication for any tables created while the connection to the grid is open
Execute from nuc10
The grid commands must be executed from coordinator nuc10.
execute procedure ifx_grid_connect('grid_all', 'tag1', 1); drop database if exists tpch100; create database tpch100 in d_data with log; create 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 table region ( r_regionkey integer not null , r_name char(25) not null , r_comment varchar(152) ) lock mode row; create 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 ); create 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 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 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; execute procedure ifx_grid_disconnect();
6.3 Create fact tables in all nodes using grid
Fact tables should be loaded individually for each node in grid. To avoid long transaction errors, we can create fact tables in raw mode.
execute procedure ifx_grid_connect('grid_all'); database tpch100; set environment autolocate '4'; -- auto fragment tables in 4 partitions 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; execute procedure ifx_grid_disconnect();
6.4 Load dimension data
Dimension tables: nation,region,customer,supplier,part and partsupp can be loaded only in one node and Informix Enterprise Replication will take care of replicate data to all other grid nodes.
Fact tables: orders and lineitem should be loaded individually in each node.
After loading process is complete, you should put fact tables: orders and lineitem back from raw to standard mode:
execute procedure ifx_grid_connect('grid_all'); ALTER TABLE orders TYPE(standard); ALTER TABLE lineitem TYPE(standard); execute procedure ifx_grid_disconnect();
6.4.1 Verify dimension data is in sync
After all data is loaded, you can verify if all data of dimension tables are in sync in the hole domain, you can use cdr command to verify and repair issues:
cdr check replicate --repair --master=g_nuc10 --all --repl=G11796481_180_29_customer --background cdr check replicate --repair --master=g_nuc10 --all --repl=G11796481_180_18_partsupp --background cdr check replicate --repair --master=g_nuc10 --all --repl=G11796481_180_16_supplier --background cdr check replicate --repair --master=g_nuc10 --all --repl=G11796481_180_14_part --background
6.5 Execute queries on Informix grid
You can execute TPCH queries using Informix grid technology. First you need to define which tables are part or informix query grid technology by executing command:
cdr change gridtable --grid=grid_all --database=tpch100 --add lineitem orders customer supplier part partsupp nation region
This command is only executed once to define tables into grid. Tables pertaining to grid can be explored by using command:
cdr list gridtable
To execute queries using Informix grid technology, execute:
EXECUTE PROCEDURE ifx_grid_connect('grid_all'); --SET ENVIRONMENT SELECT_GRID_ALL 'grid_all'; SET ENVIRONMENT SELECT_GRID 'grid_all'; SET ENVIRONMENT GRID_NODE_SKIP ON; SELECT 100.00 * SUM(CASE WHEN p_type LIKE 'PROMO%' THEN l_extendedprice * (1 - l_discount) ELSE 0 END) / SUM(l_extendedprice * (1 - l_discount)) AS promo_revenue FROM lineitem, part WHERE l_partkey = p_partkey AND l_shipdate >= MDY(9,1,1995) AND l_shipdate < MDY(9,1,1995) + 1 UNITS MONTH; EXECUTE PROCEDURE ifx_grid_disconnect();
7 Automatic load script
The following shell script performs automatic data generation at given scale factor and load. Notice you have to:
- setup DBSPACE_D for data and DBSPACE_I for indexes variables
-
provide
dbgen
executable. -
provide
dists.dss
pattern file.
if [ $# -ne 1 ] then echo "Plase, specify the scale factor" exit 1 fi # TPCH scale: 1, 10, 100, 1000 (1TB) SCALE=$1 # Path of dbgen & data generated DBGEN_EXEC=./dbgen DBGEN_DATA=`pwd`/data export DSS_PATH=data mkdir -p $DBGEN_DATA # =============================================== # dbspace for data # =============================================== DBSPACE_D=d_data # =============================================== # dbspace for indexes # =============================================== DBSPACE_I=i_data # =============================================== # table extens = (rowsize * number of rows / K) # =============================================== DIVISOR=2048 lineitem=$(((146*6000000*$SCALE)/$DIVISOR)) orders=$(((136*1500000*$SCALE)/$DIVISOR)) partsupp=$(((221*800000*$SCALE)/$DIVISOR)) part=$(((168*200000*$SCALE)/$DIVISOR)) customer=$(((227*150000*$SCALE)/$DIVISOR)) supplier=$(((200*10000*$SCALE)/$DIVISOR)) # Check max extent size min() { echo $(( $1 < $2 ? $1 : $2 )) } echo "lineitem=" $lineitem lineitem=$(min $lineitem 67108860) tcph_dbgen() { echo "-------------------------------------------------------------------" echo "GENERATE DBGEN AT SCALE $1" echo "-------------------------------------------------------------------" date time $DBGEN_EXEC -s $1 -f ls -l $DBGEN_DATA/lineitem.tbl date } tpch_create() { echo "-------------------------------------------------------------------" echo "CREATE DB" echo "-------------------------------------------------------------------" time dbaccess - - <<! drop database if exists tpch_$1; create database tpch_$1 in $DBSPACE_D; -- Timer procedure to keep track of operation times -- USE: -- timer_p('event') -- event ... -- timer_p('event') CREATE PROCEDURE timer_p(p_key varchar(60)) RETURNING VARCHAR(80) DEFINE m_dt INTERVAL HOUR TO SECOND; DEFINE m_seqno INTEGER; CREATE TABLE IF NOT EXISTS timer_t( seqno serial, key varchar(60) not null PRIMARY KEY, start datetime year to fraction default current, dt interval hour to second ); LET m_seqno = NULL; SELECT seqno INTO m_seqno FROM timer_t WHERE key = p_key; if m_seqno IS NULL THEN INSERT INTO timer_t(key) VALUES (p_key); RETURN "EVENT START : " || p_key; ELSE UPDATE timer_t SET dt = ( SELECT (current-start)::interval second(9) to fraction FROM timer_t WHERE seqno = m_seqno ) WHERE seqno = m_seqno; SELECT dt INTO m_dt FROM timer_t WHERE seqno = m_seqno; RETURN "EVENT FINISH: " || p_key || " time=" || m_dt; END IF END PROCEDURE ! } tpch_load() { echo "-------------------------------------------------------------------" echo "LOAD DATA" echo "-------------------------------------------------------------------" DBDATE=Y4MD- DBMONEY=. time dbaccess - - 2>/dev/null <<! database tpch_$1; create raw table region ( r_regionkey integer not null , r_name char(25) not null , r_comment varchar(152) ) in $DBSPACE_D lock mode row; create raw table nation ( n_nationkey integer not null , n_name char(25) not null , n_regionkey integer not null , n_comment varchar(152) ) in $DBSPACE_D 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 ) in $DBSPACE_D extent size $part next size 1024 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 ) in $DBSPACE_D extent size $supplier next size 1024 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 ) in $DBSPACE_D extent size $partsupp next size 1024 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 ) in $DBSPACE_D extent size $customer next size 1024 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 ) in $DBSPACE_D extent size $orders next size 1024 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 ) in $DBSPACE_D extent size $lineitem next size 1024 lock mode row ; create external table nation_ext sameas nation using ( datafiles("disk:/${DBGEN_DATA}/nation.tbl")); create external table region_ext sameas region using ( datafiles("disk:/${DBGEN_DATA}/region.tbl")); create external table part_ext sameas part using ( datafiles("disk:/${DBGEN_DATA}/part.tbl")); create external table supplier_ext sameas supplier using ( datafiles("disk:/${DBGEN_DATA}/supplier.tbl")); create external table partsupp_ext sameas partsupp using ( datafiles("disk:/${DBGEN_DATA}/partsupp.tbl")); create external table customer_ext sameas customer using ( datafiles("disk:/${DBGEN_DATA}/customer.tbl")); create external table orders_ext sameas orders using ( datafiles("disk:/${DBGEN_DATA}/orders.tbl")); create external table lineitem_ext sameas lineitem using ( datafiles("disk:/${DBGEN_DATA}/lineitem.tbl")); execute procedure timer_p("load region"); insert into region select * from region_ext; execute procedure timer_p("load region"); execute procedure timer_p("load nation"); insert into nation select * from nation_ext; execute procedure timer_p("load nation"); execute procedure timer_p("load supplier"); insert into supplier select * from supplier_ext; execute procedure timer_p("load supplier"); execute procedure timer_p("load customer"); insert into customer select * from customer_ext; execute procedure timer_p("load customer"); execute procedure timer_p("load part"); insert into part select * from part_ext; execute procedure timer_p("load part"); execute procedure timer_p("load partsupp"); insert into partsupp select * from partsupp_ext; execute procedure timer_p("load partsupp"); execute procedure timer_p("load orders"); insert into orders select * from orders_ext; execute procedure timer_p("load orders"); execute procedure timer_p("load lineitem"); insert into lineitem select * from lineitem_ext; execute procedure timer_p("load lineitem"); -- ================================================== -- SHOW TIMES -- ================================================== select key, dt from timer_t order by seqno; 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 orders type (standard); alter table lineitem type (standard); OUTPUT TO PIPE cat WITHOUT HEADINGS select current, 'begin update statistics' from systables where tabid=1; update statistics; OUTPUT TO PIPE cat WITHOUT HEADINGS select current, 'end update statistics' from systables where tabid=1; ! date ontape -s -F -t /dev/null } tpch_index() { echo "-------------------------------------------------------------------" echo "INDEX DB" echo "-------------------------------------------------------------------" time dbaccess - - <<! database tpch_$1; create temp table tp01 ( dt datetime year to fraction ); -- ================================================== -- SET PDQ TO 100 -- ================================================== SET PDQPRIORITY 100; -- ================================================== -- CREATE UNIQUE INDEXES -- ================================================== execute procedure timer_p("index region_pk"); create unique index region_pk on region (r_regionkey) IN $DBSPACE_I; execute procedure timer_p("index region_pk"); execute procedure timer_p("index nation_pk"); create unique index nation_pk on nation (n_nationkey) IN $DBSPACE_I; execute procedure timer_p("index nation_pk"); execute procedure timer_p("index supplier_pk"); create unique index supplier_pk on supplier (s_suppkey) IN $DBSPACE_I; execute procedure timer_p("index supplier_pk"); execute procedure timer_p("index customer_pk"); create unique index customer_pk on customer (c_custkey) IN $DBSPACE_I; execute procedure timer_p("index customer_pk"); execute procedure timer_p("index part_pk"); create unique index part_pk on part (p_partkey) IN $DBSPACE_I; execute procedure timer_p("index part_pk"); execute procedure timer_p("index partsupp_pk"); create unique index partsupp_pk on partsupp (ps_partkey, ps_suppkey) IN $DBSPACE_I; execute procedure timer_p("index partsupp_pk"); execute procedure timer_p("index lineitem_pk"); create unique index lineitem_pk on lineitem (l_orderkey, l_linenumber) IN $DBSPACE_I; execute procedure timer_p("index lineitem_pk"); execute procedure timer_p("index orders_pk"); create unique index orders_pk on orders (o_orderkey) IN $DBSPACE_I; execute procedure timer_p("index orders_pk"); -- ================================================== -- CREATE INDEXES -- ================================================== execute procedure timer_p("index nation_fk_region"); create index nation_fk_region on nation (n_regionkey) IN $DBSPACE_I; execute procedure timer_p("index nation_fk_region"); execute procedure timer_p("index supplier_fk_region"); create index supplier_fk_nation on supplier (s_nationkey) IN $DBSPACE_I; execute procedure timer_p("index supplier_fk_region"); execute procedure timer_p("index partsupp_fk_part"); create index partsupp_fk_part on partsupp (ps_partkey) IN $DBSPACE_I; execute procedure timer_p("index partsupp_fk_part"); execute procedure timer_p("index partsupp_fk_supplier"); create index partsupp_fk_supplier on partsupp (ps_suppkey) IN $DBSPACE_I; execute procedure timer_p("index partsupp_fk_supplier"); execute procedure timer_p("index customer_fk_nation"); create index customer_fk_nation on customer (c_nationkey) IN $DBSPACE_I; execute procedure timer_p("index customer_fk_nation"); execute procedure timer_p("index orders_fk_customer"); create index orders_fk_customer on orders (o_custkey) IN $DBSPACE_I; execute procedure timer_p("index orders_fk_customer"); execute procedure timer_p("index lineitem_fk_orders"); create index lineitem_fk_orders on lineitem (l_orderkey) IN $DBSPACE_I; execute procedure timer_p("index lineitem_fk_orders"); execute procedure timer_p("index lineitem_fk_part"); create index lineitem_fk_part on lineitem (l_partkey) IN $DBSPACE_I; execute procedure timer_p("index lineitem_fk_part"); execute procedure timer_p("index lineitem_fk_supplier"); create index lineitem_fk_supplier on lineitem (l_suppkey) IN $DBSPACE_I; execute procedure timer_p("index lineitem_fk_supplier"); -- ================================================== -- 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); ! } tpch_status() { echo "-------------------------------------------------------------------" echo "TIMES AND SIZES" echo "-------------------------------------------------------------------" dbaccess - - <<! database tpch_$1; select key, dt from timer_t order by seqno; OUTPUT TO PIPE cat WITHOUT HEADINGS SELECT tabname[1,20], nrows::integer, npused FROM systables WHERE tabid > 99 AND tabtype = "T" ORDER BY nrows; ! } echo echo "===================================================================" echo "TPCH SCALE $SCALE " echo "Estimated table extents" echo printf '%20s %8dK\n' lineitem $lineitem printf '%20s %8dK\n' partsupp $partsupp printf '%20s %8dK\n' part $part printf '%20s %8dK\n' customer $customer printf '%20s %8dK\n' supplier $supplier printf '%20s %8dG\n' TOTAL $((($lineitem+$partsupp+$part+$customer+$supplier)/(1024*1024))) echo "===================================================================" onstat -g cfg | grep -E "MAX_PDQPRIORITY|DS_TOTAL_MEMORY|DS_NONPDQ_QUERY_MEM" onstat -z date echo "1 dbgen" tcph_dbgen $SCALE if [ $? -ne 0 ]; then exit 1 fi echo "=====================================================" echo "Restarting Informix for data load" echo "=====================================================" #onmode -ky #oninit -v echo "2 create" tpch_create $SCALE if [ $? -ne 0 ]; then echo "Error creating database" exit 1 fi echo "3 loading" tpch_load $SCALE if [ $? -ne 0 ]; then echo "Error loading data" exit 1 fi echo "4 indexing" tpch_index $SCALE if [ $? -ne 0 ]; then echo "Error indexing data" exit 1 fi echo "5 status" tpch_status $SCALE if [ $? -ne 0 ]; then echo "Error getting status" exit 1 fi
8 Automatic execution script
You can use the following script to perform automatic and measure times for all querys
export DBDATE=Y4MD- export DBMONEY=. LOGFILE="LOGS/run-ifmx.log" mkdir -p LOGS echo "Starting TPCH " | tee -a $LOGFILE echo | tee -a $LOGFILE echo `date` | tee -a $LOGFILE echo | tee -a $LOGFILE onstat -c | grep "^SHMVIRTSIZE" | tee -a $LOGFILE onstat -c | grep "^VPCLASS" | tee -a $LOGFILE onstat -c | grep "^BUFFERPOOL" | tee -a $LOGFILE onstat -c | grep "^OPTCOMPIND" | tee -a $LOGFILE onstat -c | grep "^DS_" | tee -a $LOGFILE echo | tee -a $LOGFILE # ==================================================================== # Run with PDQ 0 and 100 # ==================================================================== for PDQ in 0 100; do # ==================================================================== # Select database scales 1 10 100 # database should be named tpch_scale # ==================================================================== for SCALE in 1 10; do LOGDIR=LOGS/IFMX-$SCALE mkdir -p $LOGDIR echo "PDQPRIORITY=$PDQPRIORITY" | tee -a $LOGFILE echo "PSORT_NPROC=$PSORT_NPROC" | tee -a $LOGFILE onstat -g glo | grep "^ cpu" | tee -a $LOGFILE printf "SQL Test\tLoop\tSF\tPDQ\tTime\t\tData\t\tIndex\t\tTemp\n" | tee -a $LOGFILE # ==================================================================== # Querys should be located under SQL/q??.sql # ==================================================================== for q in `find SQL -name 'q*.sql' | sort`; do # run on and second round FILE=$LOGDIR/`basename $q .sql`.log.$PDQ echo "Query $q" > $FILE for loop in 1 ; do onstat -z >/dev/null echo "" >> $FILE echo "LOOP $loop" >> $FILE echo "" >> $FILE t1=`date +%s` rm -f sqexplain.out echo "set explain on; " > /tmp/tpch.sql echo "set pdqpriority $PDQ; " >> /tmp/tpch.sql cat $q >> /tmp/tpch.sql # ==================================================================== # Run the test # ==================================================================== dbaccess tpch_$SCALE /tmp/tpch.sql >> $LOGDIR/`basename $q .sql`.out 2>&1 if [ $? -ne 0 ]; then t2=`date +%s` echo "$q failed" cat $LOGDIR/`basename $q .sql`.out else t2=`date +%s` mv sqexplain.out $LOGDIR/`basename $q .sql`.explain fi TIME=$((t2 - t1)) echo "QUERY=$q" >> $FILE echo "SCALE=$SCALE" >> $FILE echo "$q takes $((t2 - t1)) secs" >> $FILE echo "PDQPRIORITY=$PDQ" >> $FILE onstat -D >> $FILE 2>/dev/null # Data pages + Index pages + Temp DPAGES=`onstat -D | grep d_data_0 | awk '{ print $5 }'` IPAGES=`onstat -D | grep i_data_0 | awk '{ print $5 }'` TPAGES=`onstat -D | grep /t_tmp | awk '{sum+=$6} END {print sum}'` printf "%s\t%3d\t%3d\t%3d\t%6d\t%12d\t%10d\t%10d\n" $q $loop $SCALE $PDQ $TIME $DPAGES $IPAGES $TPAGES | tee -a $LOGFILE done echo "-- // " | tee -a $LOGFILE done # for SCALE done done echo "Finished TPCH test" >> $LOGFILE echo `date` >> $LOGFILE