Informix supports intelligent horizontal table and index partitioning, referring to it as table and index fragmentation. Fragmentation allows you to create a table that is treated as a single table in SQL statements, but consists of multiple tblspaces.

Normal fragmentation calls for one fragment per dbspace. This effectively breaks up the larger table into multiple smaller table spaces (tables) since a single table space cannot span multiple dbspaces.

The feature called partitioning allows multiple fragments from a fragmented table to coexist in the same dbspace. With partitioning, the dbspace name can no longer represent the fragment since more than one fragment can be in the same dbspace. Therefore, a partition name is added.

All fragments/partitions of a table must exist in dbspaces with the same pagesize.

1 Fragments and extents

Table fragments and index fragments are placed in designated dbspaces. Each fragment has a separate tblspace ID. The tblspace ID is also known as the fragment ID. Each tblspace contains separate extents.

1.1 Extent sizes

You need to recalculate extent sizes for a fragmented table. When you create fragmented tables, you specify the extent size for the fragment. In a non-fragmented table, the extent size is specified for the entire table. You do not specify an extent size for fragmented indexes. The extent size used for the index fragment is proportional to the size of the data fragment based on the ratio of index-key data size (including internal-key overhead) to row size.

2 Advantages of fragmentation

The primary advantages of fragmentation include:

  • Parallel scans: If you are in a decision support (DSS) environment and use the parallel database queries (PDQ) features in Informix, the database server can read multiple fragments in parallel. This is advantageous to DSS queries where large amounts of data are read.
  • Balanced I/O: By balancing I/O across disks, you can reduce disk contention and eliminate bottlenecks. This is advantageous in OLTP systems where a high degree of throughput is critical.
  • Archive and restore: Fragmentation provides for a finer granularity of archives and restores. You can perform an archive and restore at the dbspace level. Since a fragment resides in a dbspace, this means that you can perform an archive and restore at the fragment level.
  • Higher availability: You can specify whether to skip unavailable fragments in a table. This is advantageous in DSS where large amounts of data are read and processing should not be interrupted if a particular fragment is unavailable.
  • Increased security: You can grant different permissions to each fragment, thereby increasing security.
  • Other operations: Other parallelized operations include: joins, sorts, aggregates, groups, and inserts.

2.1 Parallel scans and fragmentation

One of the benefits of fragmentation is that it enables parallel scans. A parallel scan is the simultaneous access of multiple fragments from the same table. In Informix, a single query can have multiple threads of execution and each thread can potentially access a different fragment.

A query can have multiple threads on a single processor computer but only one thread executes at a time. The optimum situation is to execute parallel queries on a multiprocessor computer where many threads can execute simultaneously.

Parallel database query, or PDQ, is the feature of Informix that permits queries to be parallelized. Informix allows to you turn parallelism on and off by using the SET PDQPRIORITY SQL statement or the PDQPRIORITY environment variable.

To enable parallelism for a group of SQL statements, use the SET PDQPRIORITY statement. The degree of parallelism specified remains in effect until the next SET PDQPRIORITY statement is executed or until the end of the process.

To enable parallelism for all statements that a user or process executes, set the PDQPRIORITY environment variable. The SET PDQPRIORITY statement overrides the environment variable setting.

2.2 Balanced I/O and fragmentation

You can use fragmentation to balance I/O across disk drives. Individual users can access different fragments of the same table and not be in contention. Balanced I/O is more important than parallelism in online transaction processing (OLTP) environments because maximum throughput of many concurrent queries is critical.

3 Types of distribution schemes

Informix provides two types of distribution schemes:

  • Round robin.
  • Expression-based.

3.1 Round robin

  • Round robin fragmentation creates even data distributions by randomly placing rows in fragments.
  • For insert statements, the database server uses a hash function on a random number to determine in which fragment to place the row.
  • For insert cursors, the database server places the first row in a random fragment, the second in the next fragment, and so on, in a true round robin fashion.

3.2 Expression-based

  • Expression-based fragmentation allows you to use any WHERE condition as a fragmentation expression for your table or index.
  • The expression can be any valid expression that the database server recognizes. You can specify a fragmentation expression based on a range condition for one column and equality conditions for another column.
  • Informix also allows you to specify a remainder fragment to store all rows that do not match criteria specified for any other fragment.

4 Round robin fragmentation

Example
Copy
CREATE TABLE person(
    id        INTEGER NOT NULL,
    name      CHAR(32) NOT NULL,
    age       INTEGER,
    birthdate DATE)
   FRAGMENT BY ROUND ROBIN IN dbs1, dbs2
   EXTENT SIZE 10000 NEXT SIZE 3000 LOCK MODE ROW;
  • Rows are placed randomly among the listed dbspaces.
  • The FRAGMENT BY ROUND ROBIN option must specify at least two dbspaces where the fragments are to be placed.
  • EXTENT SIZE and NEXT SIZE refer to the size of each table fragment, not the size of the entire table.
  • When a table is created, one extent of the size specified by EXTENT SIZE is reserved in each dbspace listed.
  • Calculate EXTENT SIZE and NEXT SIZE based on an average size fragment.

4.1 Advantages and disadvantages

The major advantage of the round robin strategy is that you do not need knowledge of the data to achieve an even distribution among the fragments. Also, when column values are updated, rows are not moved to other fragments because the distribution does not depend on column values.

A disadvantage of the round robin strategy is that the query optimizer is not able to eliminate fragments when it evaluates a query.

Use the round robin distribution strategy when your queries perform sequential scans and you have little information about the data being stored. For example, consider using round robin when the data access method or the data distribution is unknown. Round robin can also be useful when your application is update intensive, or when loading data quickly is important.

4.2 Round robin for smart large objects

Example
Copy
CREATE TABLE movie(
   movie_num INTEGER,
   movie_title CHAR(50),
   video BLOB,
   audio BLOB,
   description CLOB)
   PUT video IN (sbsp3, sbsp6, sbsp7),
       audio IN (sbsp1, sbsp2, sbsp4),
       description IN (sbsp5);

Unless the PUT clause is used, the database server stores smart large objects in the default sbspace (identified in the system catalog table SBSPACENAME.)

It is possible to fragment smart large objects over multiple sbspaces. Although smart large objects might be distributed among multiple sbspaces, each individual smart large object is stored entirely within one sbspace. The only method of fragmentation available is round robin. If your business needs require expression-based fragmentation, it needs to be implemented at the DataBlade level where you have direct control over where each smart large object is stored.

In the example, three smart large object columns are fragmented over seven sbspaces. The order in which the sbspaces are used is not guaranteed, but the distribution is relatively even. Each time the database server is restarted, the distribution starts over again from the first sbspace in the list.

The fragmentation for smart large objects is also independent of the storage of the data rows associated with them. The traditional columns associated with the smart large objects (here, movie_num and movie_title) can be fragmented by expression, round robin, or not fragmented at all. In this example, they are not fragmented at all.

5 Expression-based fragmentation

Example
Copy
CREATE TABLE person(
    id        INTEGER NOT NULL,
    name      CHAR(32) NOT NULL,
    age       INTEGER,
    birthdate DATE
) FRAGMENT BY EXPRESSION
     id <= 10000 AND id >= 1 IN dbs1,
     id <= 20000 AND id > 10000 IN dbs2,
     REMAINDER IN dbs3;

The FRAGMENT BY EXPRESSION option provides control in placing rows in fragments. You specify a series of SQL expressions and designated dbspaces. If the expression is evaluated to true, the row is placed in the corresponding dbspace.

Each expression is evaluated in order. The row is placed in the first fragment where the expression evaluates to true and the rest of the expressions are skipped.

The REMAINDER IN clause specifies a dbspace that holds rows that do not evaluate into any of the expressions.

You can use any column in the table as part of the expression. Columns in other local or remote tables are not allowed. No subqueries or stored procedures are allowed as part of the expression.

Only one fragment can exist in a dbspace, meaning that a dbspace can only be listed once in the fragmentation scheme.

5.1 Using PARTITIONING

Example
Copy
CREATE TABLE person (
    id        INTEGER NOT NULL,
    name      CHAR(32) NOT NULL,
    age       INTEGER,
    birthdate DATE
) PARTITION BY EXPRESSION
      PARTITION part1 (id >=0 AND id < 5)  IN dbs1,
      PARTITION part2 (id >=5 AND id < 10) IN dbs1,
      PARTITION part3 REMAINDER IN dbs2;

Partitioning, an enhancement to fragmentation, allows multiple fragments to be stored in the same dbspace. In order to use this feature, use the PARTITION keyword and give the partition a name.

Partition information is stored in the sysfragments table. If a fragmented table is created with partitions, each row in the sysfragments catalog contains a partition name in the partition column. If a regular fragmented table without partitions is created, the name of the dbspace appears in the partition column.

Remark

You can also use the syntax FRAGMENT BY instead of PARTITION BY when creating a partitioned table.

5.2 Logical and relational operators

An expression-based distribution scheme uses an expression or rule to define which rows are inserted into specific fragments. Each condition in the rule determines the contents of one fragment.

You can use the following relational and logical operators in a rule:

  • >, <, >=, <=, IN, BETWEEN
  • AND, OR

A single condition can use multiple operators and can reference multiple columns. It is suggested, however, that you keep conditions as simple as possible to minimize CPU use and to promote fragment elimination from query plans.

5.3 Advantages and disadvantages

Distributing data by expression has many potential advantages:

  • Fragments can be eliminated from query scans.
  • Data can be segregated to support a particular archiving strategy.
  • Users can be granted privileges at the fragment level.
  • Unequal data distributions can be created to offset an unequal frequency of access.

A disadvantage of distributing data by expressions is that CPU resources are required for rule evaluation. As the rule becomes more complex, more CPU time is consumed.

Also, more administrative work is required with expression-based fragmentation than with round robin. Finding the optimum rule can be an iterative process. Once found, it might need to be monitored and modified over time.

The goal of expression-based fragmentation is to increase I/O throughput and fragment elimination during query optimization. The optimum situation for fragment elimination is when expression conditions involve a single column and do not overlap.

Consider using an expression strategy when:

  • Non-overlapping fragments on a single column can be created.
  • The table is accessed with a high degree of selectivity.
  • The data access is not evenly distributed.

5.4 Fragmentation by expression guidelines

Once you have determined that fragmenting by expression is the optimal fragmentation strategy for you, additional guidelines can help you maximize your strategy:

  • A remainder fragment is always scanned.
  • Distribute data so that I/O activity is balanced across disks.
  • Fragmentation expressions can be as complex as you want. However, complex expressions take more CPU time to evaluate and can prevent the database server from eliminating fragments.
  • Arrange the conditions so the most restrictive part comes first.
  • Avoid any expression that must perform a conversion.
  • Optimize data loads by placing the most frequently accessed fragment first in your fragmentation statement.
  • If a significant benefit is not expected, do not fragment the table.

5.5 Fragmentation based on a list

A list fragmentation strategy partitions data into a set of fragments that are each defined by a list of discrete values of the fragment key. Every expression must be a quoted string or a literal value. Each value in the list must be unique among the lists for fragments of the same object.

To fragment based on a list of values, use the following syntax for the fragment expression:

Copy
FRAGMENT BY LIST  
   PARTITION partition VALUES (expression_list) IN dbspace,
   . . . 
   PARTITION partition VALUES (expression_list) IN dbspace,
   PARTITION partition VALUES (NULL) IN dbspace,
   PARTITION partition REMAINDER IN dbspace

Here the last two partitions (whose expressions define a NULL fragment and a REMAINDER fragment) are not required.

  • The null fragment is the fragment that holds rows that have NULL values for the fragment key column. You cannot include NULL in an expression list with other values that define the same fragment.
  • The remainder fragment holds rows that do not fit in the explicitly defined fragments; it must be the last fragment. If you define a REMAINDER fragment but no NULL fragment, rows with the fragment key value missing are stored in the REMAINDER fragment.
Example

Fragmentation based on selected states:

Copy
CREATE TABLE customer (
   cust_id INT,
   name CHAR(128),
   street CHAR(1024),
   state CHAR(2), 
   zipcode CHAR(5),
   phone CHAR(12)
) FRAGMENT BY LIST(state)
    PARTITION p0 VALUES ('KS','IL') IN dbspace1,
    PARTITION p1 VALUES ('CA','OR') IN dbspace2,
    PARTITION p2 VALUES ('NY','MN') IN dbspace3,
    PARTITION p3 VALUES (NULL) IN dbspace4,
    PARTITION p4 REMAINDER IN dbspace4;

Warning

The database server throws an exception for INSERT operations if the value of the fragment key for an inserted row does not match any expression in the fragment and no REMAINDER fragment is defined. Similarly, an exception is thrown if data is missing in the fragment key column, but the fragment list does not include the NULL fragment or the REMAINDER fragment.

Remark

When you use the CREATE INDEX statement to define an index on a table that is fragmented by list, it is not necessary to include the FRAGMENT BY or PARTITION BY clause to create indexes that use the same list fragmentation strategy as their table. By default, the database server partitions the index by the same list fragmentation strategy as its table, and declares for each index fragment the same name that you specified after the PARTITION keyword for the corresponding table fragment.
Example
Copy
create index idx_customer_1  on customer (zipcode);
create index idx_customer_2  on customer (state);
Copy
$ oncheck -pt test:customer |grep idx_customer_1
                  Index idx_customer_1 fragment partition p0 in DBspace dbspace1
                  Index idx_customer_1 fragment partition p1 in DBspace dbspace2
                  Index idx_customer_1 fragment partition p2 in DBspace dbspace3
                  Index idx_customer_1 fragment partition p3 in DBspace dbspace4
                  Index idx_customer_1 fragment partition p4 in DBspace dbspace4
                  
$ oncheck -pt test:customer |grep idx_customer_2
                  Index idx_customer_2 fragment partition p0 in DBspace dbspace1
                  Index idx_customer_2 fragment partition p1 in DBspace dbspace2
                  Index idx_customer_2 fragment partition p2 in DBspace dbspace3
                  Index idx_customer_2 fragment partition p3 in DBspace dbspace4
                  Index idx_customer_2 fragment partition p4 in DBspace dbspace4

5.6 Fragmentation based on an interval

An interval fragmentation strategy partitions data into fragments based on an interval value of the fragment key.

The interval value must be a column expression that references a single column of a NUMERIC,DATE, or DATETIME data type.

The syntax for defining the parameters of a range interval distribution has the following form:

Copy
FRAGMENT BY RANGE (column_expr) 
      INTERVAL (interval_size) STORE IN (dbspace_list)
         PARTITION partition VALUES < upper_bound IN dbspace_name,
                  . . . 
         PARTITION partition VALUES < upper_bound IN dbspace_name,
         PARTITION partition VALUES IS NULL IN dbspace_name
  • RANGE(column_expr): Must be a single column or column expression of DATE, DATETIME, or NUMERIC type.
  • INTERVAL(interval_size): Interval value expression that defines an interval size in the fragment key range. Must be a constant literal expression that evaluates to a NUMERIC or INTERVAL value compatible with the data type of the fragment key expression.
  • dbspace_list: Name of a dbspace to store a fragment. You can specify no more than 2,048 dbspaces and all dbspaces that store the fragments must have the same page size.
  • upper_bound : Constant expression that defines the upper bound for fragment key values stored in the fragment. Must be a constant literal expression that evaluates to a NUMERIC, DATETIME, or DATE data type compatible with the data type of the fragment key expression.
  • dbspace_name : The name of the first fragment used and is based on the specified VALUES range.
  • IS NULL operator: You can use this to define the NULL fragment that stores only the rows with NULL as their fragment key value.
Example

Fragment by integer values:

  • The fragment key is the value of the person.age column.
  • The value of the interval size is 20.
  • p0 is the table fragment to store rows that have no age column value.
Copy
CREATE TABLE person (id INTEGER NOT NULL, name CHAR(32) NOT NULL, age INTEGER) 
       FRAGMENT BY RANGE (age) 
       INTERVAL (20) STORE IN (dbs1, dbs2, dbs3, dbs4)
             PARTITION p0 VALUES IS NULL IN dbs0,
             PARTITION p1 VALUES < 5 IN dbs1,
             PARTITION p2 VALUES < 10 IN dbs2;
id name               age partition dbspace

 1 AGE NULL               p0        dbs0
 2 AGE <5               2 p1        dbs1
 3 AGE <5               4 p1        dbs1
 4 5<=AGE<10            5 p2        dbs2
 5 5<=AGE<10            9 p2        dbs2
 6 10<=AGE<30          10 sys_p3    dbs3
 7 10<=AGE<30          27 sys_p3    dbs3
 8 30<=AGE<50          49 sys_p4    dbs4
 9 30<=AGE<50          48 sys_p4    dbs4

Fragment by year intervals:

  • The fragment key is the value of the person.birthdate column.
  • The value of the interval size is 5-year.
  • p0 is the table fragment to store rows that have no age column value.
Copy
CREATE TABLE person (id INTEGER NOT NULL, name CHAR(32) NOT NULL, birthdate DATE)
       FRAGMENT BY RANGE (birthdate)
       INTERVAL (INTERVAL(5) YEAR(2) TO YEAR) STORE IN (dbs1, dbs2, dbs3, dbs4)
             PARTITION p0 VALUES IS NULL IN dbs0,
             PARTITION p1 VALUES < DATE('01-01-1960') IN dbs1,
             PARTITION p2 VALUES < DATE('01-01-1970') IN dbs2;

OR:

CREATE TABLE person (id INTEGER NOT NULL, name CHAR(32) NOT NULL, birthdate DATE)
       FRAGMENT BY RANGE (birthdate)
       INTERVAL (NUMTOYMINTERVAL (5,'YEAR')) STORE IN (dbs1, dbs2, dbs3, dbs4)
             PARTITION p0 VALUES IS NULL IN dbs0,
             PARTITION p1 VALUES < DATE('01-01-1960') IN dbs1,
             PARTITION p2 VALUES < DATE('01-01-1970') IN dbs2;
 
 OR:
 
 CREATE TABLE person (id INTEGER NOT NULL, name CHAR(32) NOT NULL, birthdate DATE)
       FRAGMENT BY RANGE (birthdate)
       INTERVAL (5 UNITS YEAR) STORE IN (dbs1, dbs2, dbs3, dbs4)
             PARTITION p0 VALUES IS NULL IN dbs0,
             PARTITION p1 VALUES < DATE('01-01-1960') IN dbs1,
             PARTITION p2 VALUES < DATE('01-01-1970') IN dbs2;
id name                 birthdate  partition dbspace

 1 BIRTHDATE NULL                  p0        dbs0
 2 BIRTHDATE <1960      01-02-1955 p1        dbs1
 3 BIRTHDATE <1960      01-03-1959 p1        dbs1
 4 1960<=BIRTHDATE<1970 03-01-1960 p2        dbs2
 5 1960<=BIRTHDATE<1970 31-12-1969 p2        dbs2
 6 1970<=BIRTHDATE<1975 01-01-1970 sys_p3    dbs3
 7 1970<=BIRTHDATE<1975 31-12-1974 sys_p3    dbs3
 8 1975<=BIRTHDATE<1980 02-04-1976 sys_p4    dbs4
 9 1975<=BIRTHDATE<1980 12-12-1979 sys_p4    dbs4

Fragment by month intervals:

  • The fragment key is the value of the person.birthdate column.
  • The value of the interval size is 18-month.
  • p0 is the table fragment to store rows that have no age column value.
Copy
CREATE TABLE person (id INTEGER NOT NULL, name CHAR(32) NOT NULL, birthdate DATE)
       FRAGMENT BY RANGE (birthdate)
       INTERVAL (INTERVAL(18) MONTH(4) TO MONTH) STORE IN (dbs1, dbs2, dbs3, dbs4)
             PARTITION p0 VALUES IS NULL IN dbs0,
             PARTITION p1 VALUES < DATE('01-01-1960') IN dbs1,
             PARTITION p2 VALUES < DATE('01-01-1970') IN dbs2;

OR:

CREATE TABLE person (id INTEGER NOT NULL, name CHAR(32) NOT NULL, birthdate DATE)
       FRAGMENT BY RANGE (birthdate)
       INTERVAL (NUMTOYMINTERVAL (1.5,'YEAR')) STORE IN (dbs1, dbs2, dbs3, dbs4)
             PARTITION p0 VALUES IS NULL IN dbs0,
             PARTITION p1 VALUES < DATE('01-01-1960') IN dbs1,
             PARTITION p2 VALUES < DATE('01-01-1970') IN dbs2;
 
OR:

CREATE TABLE person (id INTEGER NOT NULL, name CHAR(32) NOT NULL, birthdate DATE)
       FRAGMENT BY RANGE (birthdate)
       INTERVAL (NUMTOYMINTERVAL (18,'MONTH')) STORE IN (dbs1, dbs2, dbs3, dbs4)
             PARTITION p0 VALUES IS NULL IN dbs0,
             PARTITION p1 VALUES < DATE('01-01-1960') IN dbs1,
             PARTITION p2 VALUES < DATE('01-01-1970') IN dbs2;


 OR:
 
 CREATE TABLE person (id INTEGER NOT NULL, name CHAR(32) NOT NULL, birthdate DATE)
       FRAGMENT BY RANGE (birthdate)
       INTERVAL (18 UNITS MONTH) STORE IN (dbs1, dbs2, dbs3, dbs4)
             PARTITION p0 VALUES IS NULL IN dbs0,
             PARTITION p1 VALUES < DATE('01-01-1960') IN dbs1,
             PARTITION p2 VALUES < DATE('01-01-1970') IN dbs2;
id name                       birthdate  partition dbspace

 1 BIRTHDATE NULL                        p0        dbs0
 2 BIRTHDATE <1960            01-02-1955 p1        dbs1
 3 BIRTHDATE <1960            01-03-1959 p1        dbs1
 4 1960<=BIRTHDATE<01-1970    03-01-1960 p2        dbs2
 5 1960<=BIRTHDATE<01-1970    31-12-1969 p2        dbs2
 6 01-1970<=BIRTHDATE<07-1971 01-01-1970 sys_p3    dbs3
 7 01-1970<=BIRTHDATE<07-1971 30-06-1971 sys_p3    dbs3
 8 07-1971<=BIRTHDATE<01-1973 01-07-1972 sys_p4    dbs4
 9 07-1971<=BIRTHDATE<01-1973 31-12-1972 sys_p4    dbs4

5.7 Strategy for fragmenting indexes

You can decide whether or not you want to fragment indexes. If you fragment your indexes, you must use an expression-based fragmentation scheme. You cannot use round robin fragmentation for indexes.

System indexes, created to support constraints, remain unfragmented and are created in the dbspace where the database is created.

If you do not specify a dbspace (nonfragmented) or list of dbspaces (fragmented), then the index defaults to the same fragmentation strategy as the table. This scenario is not desirable if your table is fragmented by round robin. It is recommended that you specify a dbspace for your indexes in this scenario.

A FRAGMENT BY EXPRESSION option is available for the CREATE INDEX statement. If you do not want to fragment your indexes, specify the dbspace where you want the entire index to be located.

Example

By expression:

Copy
CREATE INDEX idx1 ON person(id)
   FRAGMENT BY EXPRESSION
     id < 10000  IN dbs1,
     id >= 10000 IN dbs2;

No fragmentation scheme is specified:

Copy
CREATE INDEX idx1 ON person(id) IN dbs1;

Partitioned:

Copy
CREATE INDEX idx1 ON person(id)
   PARTITION BY EXPRESSION
      PARTITION ix_part1 id < 10000 IN dbs1,
      PARTITION ix_part2 id >= 10000 IN dbs1;

6 Rowids in a fragmented table

Unlike rows in a nonfragmented table, the database server does not assign a rowid to rows in fragmented tables. If you want to access data by rowid, you must explicitly create a rowid column.

To create the rowid column, use the following SQL syntax:

  • The WITH ROWIDS clause of the CREATE TABLE statement:
    Copy
    CREATE TABLE person (id INTEGER NOT NULL, name CHAR(32) NOT NULL, age INTEGER) 
           WITH ROWIDS
           FRAGMENT BY RANGE (age) 
           INTERVAL (20) STORE IN (dbs1, dbs2, dbs3, dbs4)
                 PARTITION p0 VALUES IS NULL IN dbs0,
                 PARTITION p1 VALUES < 5 IN dbs1,
                 PARTITION p2 VALUES < 10 IN dbs2;
  • The ADD ROWIDS clause of the ALTER TABLE statement:
    Copy
    ALTER TABLE person ADD ROWIDS;
  • The INIT clause of the ALTER FRAGMENT statement:
    Copy
    ALTER FRAGMENT ON TABLE person INIT
           WITH ROWIDS
           FRAGMENT BY RANGE (age) 
           INTERVAL (20) STORE IN (dbs1, dbs2, dbs3, dbs4)
                 PARTITION p0 VALUES IS NULL IN dbs0,
                 PARTITION p1 VALUES < 5 IN dbs1,
                 PARTITION p2 VALUES < 10 IN dbs2;

7 Maintaining table and index partitioning

Use the ALTER FRAGMENT statement to change the distribution strategy or the storage location of an existing table or index.

  • ALTER FRAGMENT ... INIT: Initialize a new fragmentation scheme.
  • ALTER FRAGMENT ... ADD: Add an additional fragment.
  • ALTER FRAGMENT ... DROP: Drop a fragment.
  • ALTER FRAGMENT ... MODIFY: Modify a fragmentation expression or dbspace.
  • ALTER FRAGMENT ... ATTACH or DETACH: Combine tables into a single fragmented table, or Move a fragment into a separate table.

7.1 Initializing a new fragmentation strategy

The INIT clause of the ALTER FRAGMENT statement can do any of the following:

  • Make a fragmented table non-fragmented:
    Copy
    ALTER FRAGMENT ON TABLE person INIT IN dbs1;
  • Make a non-fragmented table fragmented:
    Copy
    ALTER FRAGMENT ON TABLE person INIT
           FRAGMENT BY RANGE (age) 
           INTERVAL (20) STORE IN (dbs1, dbs2, dbs3, dbs4)
                 PARTITION p0 VALUES IS NULL IN dbs0,
                 PARTITION p1 VALUES < 5 IN dbs1,
                 PARTITION p2 VALUES < 10 IN dbs2;
  • Completely change the fragmentation strategy:
    Copy
    ALTER FRAGMENT ON TABLE person INIT 
       FRAGMENT BY ROUND ROBIN IN dbs1, dbs2;

7.2 Adding an additional fragment

Use the ADD clause to add another fragment to a list of fragments of an existing table or index.

Example

We assume that the person table has the following scheme:

Copy
CREATE TABLE person(
    id        INTEGER NOT NULL,
    name      CHAR(32) NOT NULL,
    age       INTEGER,
    birthdate DATE
) FRAGMENT BY EXPRESSION
     id <= 10 AND id >= 1 IN dbs1,
     id <= 20 AND id > 10 IN dbs2,
     REMAINDER IN dbs0;
id name       partition dbspace

10 1<=id<=10  dbs1      dbs1
11 10<id<=20  dbs2      dbs2
21 REMAINDER  dbs0      dbs0
31 REMAINDER  dbs0      dbs0
41 REMAINDER  dbs0      dbs0
51 REMAINDER  dbs0      dbs0

Add new dbspace for expression-based fragmentation:

Copy
ALTER FRAGMENT ON TABLE person ADD id <= 40 AND id > 30 IN dbs4;

Insert a new condition before another:

Copy
ALTER FRAGMENT ON TABLE person ADD id <= 30 AND id > 20 IN dbs3 BEFORE dbs4;

After executing the alter fragment statement, the scheme of the table is as follows:

Copy
CREATE TABLE person(
    id        INTEGER NOT NULL,
    name      CHAR(32) NOT NULL,
    age       INTEGER,
    birthdate DATE
) FRAGMENT BY EXPRESSION
    id <= 10 AND id >= 1 IN dbs1,
    id <= 20 AND id > 10 IN dbs2,
    id <= 30 AND id > 20 IN dbs3,
    id <= 40 AND id > 30 IN dbs4,
    REMAINDER IN dbs0;
id name       partition dbspace

10 1<=id<=10  dbs1      dbs1
11 10<id<=20  dbs2      dbs2
21 20<id<=30  dbs3      dbs3
31 30<id<=40  dbs4      dbs4
41 REMAINDER  dbs0      dbs0
51 REMAINDER  dbs0      dbs0
Example

We assume that the person table has the following scheme:

Copy
CREATE TABLE person(
    id        INTEGER NOT NULL,
    name      CHAR(32) NOT NULL,
    age       INTEGER,
    birthdate DATE)
   FRAGMENT BY ROUND ROBIN IN dbs1, dbs2
   EXTENT SIZE 10000 NEXT SIZE 3000 LOCK MODE ROW;

Add another dbspace for round robin fragmentation:

Copy
ALTER FRAGMENT ON TABLE person ADD dbs3;

After executing the alter fragment statement, the scheme of the table is as follows:

Copy
CREATE TABLE person(
    id        INTEGER NOT NULL,
    name      CHAR(32) NOT NULL,
    age       INTEGER,
    birthdate DATE)
   FRAGMENT BY ROUND ROBIN IN dbs1, dbs2, dbs3
   EXTENT SIZE 10000 NEXT SIZE 3000 LOCK MODE ROW;

7.3 Dropping a fragment

Use the DROP clause to drop a fragment and move all the rows (or index keys) in the dropped fragment to another fragment.

Example

We assume that the person table has the following scheme:

Copy
CREATE TABLE person(
    id        INTEGER NOT NULL,
    name      CHAR(32) NOT NULL,
    age       INTEGER,
    birthdate DATE
) FRAGMENT BY EXPRESSION
     id <= 10 AND id >= 1 IN dbs1,
     id <= 20 AND id > 10 IN dbs2,
     REMAINDER IN dbs0;
id name       partition dbspace

10 1<=id<=10  dbs1      dbs1
11 10<id<=20  dbs2      dbs2
21 REMAINDER  dbs0      dbs0
31 REMAINDER  dbs0      dbs0
41 REMAINDER  dbs0      dbs0
51 REMAINDER  dbs0      dbs0

Drop dbspace named dbs2:

Copy
ALTER FRAGMENT ON TABLE person DROP dbs2;

After executing the alter fragment statement, the scheme of the table is as follows:

Copy
CREATE TABLE person(
    id        INTEGER NOT NULL,
    name      CHAR(32) NOT NULL,
    age       INTEGER,
    birthdate DATE
) FRAGMENT BY EXPRESSION
     id <= 10 AND id >= 1 IN dbs1,
     REMAINDER IN dbs0;
id name       partition dbspace

10 1<=id<=10  dbs1      dbs1
11 REMAINDER  dbs0      dbs0
21 REMAINDER  dbs0      dbs0
31 REMAINDER  dbs0      dbs0
41 REMAINDER  dbs0      dbs0
51 REMAINDER  dbs0      dbs0
Example

We assume that the person table has the following scheme:

Copy
CREATE TABLE person (id INTEGER NOT NULL, name CHAR(32) NOT NULL, age INTEGER) 
       FRAGMENT BY RANGE (age) 
       INTERVAL (20) STORE IN (dbs1, dbs2, dbs3, dbs4)
             PARTITION p0 VALUES IS NULL IN dbs0,
             PARTITION p1 VALUES < 5 IN dbs1,
             PARTITION p2 VALUES < 10 IN dbs2;
id name               age partition dbspace

  1 AGE NULL               p0        dbs0
  2 AGE <5               2 p1        dbs1
  3 AGE <5               4 p1        dbs1
  4 5<=AGE<10            5 p2        dbs2
  5 5<=AGE<10            9 p2        dbs2
  6 10<=AGE<30          10 sys_p3    dbs3
  7 10<=AGE<30          27 sys_p3    dbs3
  8 30<=AGE<50          49 sys_p4    dbs4
  9 30<=AGE<50          48 sys_p4    dbs4

Drop partition named p1:

Copy
ALTER FRAGMENT ON TABLE person DROP PARTITION p1;

After executing the alter fragment statement, the scheme of the table is as follows:

Copy
CREATE TABLE person (id INTEGER NOT NULL, name CHAR(32) NOT NULL, age INTEGER) 
       FRAGMENT BY RANGE (age) 
       INTERVAL (20) STORE IN (dbs1, dbs2, dbs3, dbs4)
             PARTITION p0 VALUES IS NULL IN dbs0,
             PARTITION p2 VALUES < 10 IN dbs2;
id name               age partition dbspace

   1 AGE NULL               p0        dbs0
   2 AGE <10              2 p2        dbs2
   3 AGE <10              4 p2        dbs2
   4 AGE <10              5 p2        dbs2
   5 AGE <10              9 p2        dbs2
   6 10<=AGE<30          10 sys_p2    dbs3
   7 10<=AGE<30          27 sys_p2    dbs3
   8 30<=AGE<50          49 sys_p3    dbs4
   9 30<=AGE<50          48 sys_p3    dbs4
Example

We assume that the index ix1_person in the table of person has the following scheme:

Copy
CREATE INDEX ix1_person ON person (id)
 FRAGMENT BY EXPRESSION
     id <= 10 AND id >= 1 IN dbs1,
     id <= 20 AND id > 10 IN dbs2,
     REMAINDER IN dbs0;

Drop dbspace named dbs2:

Copy
ALTER FRAGMENT ON INDEX ix1_person DROP dbs2;

After executing the alter fragment statement, the scheme of the index is as follows:

Copy
CREATE INDEX ix1_person ON person (id)
 FRAGMENT BY EXPRESSION
     id <= 10 AND id >= 1 IN dbs1,
     REMAINDER IN dbs0;

7.4 Modifying an existing fragment

Use the MODIFY clause to change the expression or dbspace for a fragment.

Example

We assume that the person table has the following scheme:

Copy
CREATE TABLE person(
    id        INTEGER NOT NULL,
    name      CHAR(32) NOT NULL,
    age       INTEGER,
    birthdate DATE
) FRAGMENT BY EXPRESSION
     id <= 10 AND id >= 1 IN dbs1,
     id <= 20 AND id > 10 IN dbs2,
     REMAINDER IN dbs0;
id name               partition dbspace

10 1<=id<=10          dbs1      dbs1
11 10<id<=20          dbs2      dbs2
21 REMAINDER          dbs0      dbs0
31 REMAINDER          dbs0      dbs0
41 REMAINDER          dbs0      dbs0
51 REMAINDER          dbs0      dbs0

Modify the expression of the dbspace named dbs2:

Copy
ALTER FRAGMENT ON TABLE person MODIFY dbs2 TO id <= 50 AND id > 10 IN dbs2;

Modify the dbspace named dbs1 To dbs3:

Copy
ALTER FRAGMENT ON TABLE person MODIFY dbs1 TO id <= 10 AND id >= 1 IN dbs3;

Modify the dbspace remainder To dbs1:

Copy
ALTER FRAGMENT ON TABLE person MODIFY dbs0 TO  REMAINDER IN dbs1;

After executing the alter fragment statement, the scheme of the table is as follows:

Copy
CREATE TABLE person(
    id        INTEGER NOT NULL,
    name      CHAR(32) NOT NULL,
    age       INTEGER,
    birthdate DATE
) FRAGMENT BY EXPRESSION
     id <= 10 AND id >= 1 IN dbs3,
     id <= 50 AND id > 10 IN dbs2,
     REMAINDER IN dbs1;
id name               partition dbspace

10 1<=id<=10          dbs3      dbs3
11 10<id<=50          dbs2      dbs2
21 10<id<=50          dbs2      dbs2
31 10<id<=50          dbs2      dbs2
41 10<id<=50          dbs2      dbs2
51 REMAINDER          dbs1      dbs1

7.5 Attaching and detaching fragments

The ATTACH and DETACH clauses provide additional flexibility in modifying fragmented tables.

  • Use the ATTACH clause of the ALTER FRAGMENT ON TABLE statement to combine tables that have identical structures into a table with the same fragmentation strategy.
    • Both tables must have identical schemas and must be in different dbspaces.
    • You cannot attach a table if a primary-key or unique constraint exists on the surviving table or consumed table.
    • Cannot attach tables that contain serial fields.
  • Use the DETACH clause of the ALTER FRAGMENT ON TABLE statement to detach a table fragment from a storage distribution scheme and place the contents into a new nonfragmented table.
    • Cannot detach a table with rowids.

7.5.1 Attach two non fragmented tables

Example

Scheme for the surviving table:

Copy
CREATE TABLE person_surviving
  (
    id        INTEGER NOT NULL ,
    name      CHAR(32) NOT NULL ,
    age       INTEGER
  ) IN dbs1;
id name               age partition dbspace

 1 Name 1              10 dbs1      dbs1
 2 Name 2              15 dbs1      dbs1
 3 Name 3              12 dbs1      dbs1
 4 Name 4              25 dbs1      dbs1
 5 Name 5              55 dbs1      dbs1
 6 Name 6              22 dbs1      dbs1

Scheme for the consumed table:

Copy
CREATE TABLE person_consumed
  (
    id        INTEGER NOT NULL ,
    name      CHAR(32) NOT NULL ,
    age       INTEGER
  ) IN dbs2;
id name               age partition dbspace

 7 Name 7              17 dbs2      dbs2
 8 Name 8              45 dbs2      dbs2
 9 Name 9              29 dbs2      dbs2

Merge the person_surviving and person_consumed tables into a single table named person_surviving:

Copy
ALTER FRAGMENT ON TABLE person_surviving ATTACH person_surviving, person_consumed;

After executing the alter fragment statement, the scheme of the table person_surviving is as follows:

Copy
CREATE TABLE person_surviving
  (
    id        INTEGER NOT NULL ,
    name      CHAR(32) NOT NULL ,
    age       INTEGER
  ) FRAGMENT BY ROUND ROBIN in dbs1 , dbs2;
id name               age partition dbspace

 1 Name 1              10 dbs1      dbs1
 2 Name 2              15 dbs1      dbs1
 3 Name 3              12 dbs1      dbs1
 4 Name 4              25 dbs1      dbs1
 5 Name 5              55 dbs1      dbs1
 6 Name 6              22 dbs1      dbs1
 7 Name 7              17 dbs2      dbs2
 8 Name 8              45 dbs2      dbs2
 9 Name 9              29 dbs2      dbs2

7.5.2 Attach non fragmented tables to fragmented table by range

Example

Scheme for the surviving table:

Copy
CREATE TABLE person_surviving
  (
    id        INTEGER NOT NULL ,
    name      CHAR(32) NOT NULL ,
    age       INTEGER,
    fecreg    DATETIME YEAR TO SECOND
  ) FRAGMENT BY RANGE (fecreg) INTERVAL (INTERVAL(1) MONTH(9) TO MONTH) STORE IN (dbs1)
    PARTITION p0 VALUES < DATETIME(2018-01-01 00:00:00) YEAR TO SECOND IN dbs2;
id name       fecreg              partition dbspace

 1 Paul       2017-12-31 00:00:00 p0        dbs2
 2 Alisa      2017-10-20 00:00:00 p0        dbs2
 3 Conall     2018-01-15 00:00:00 sys_p1    dbs1
 4 Duncan     2018-01-23 00:00:00 sys_p1    dbs1
 5 Archie     2019-01-02 00:00:00 sys_p13   dbs1

Scheme for the consumed table:

Copy
CREATE TABLE person_consumed
  (
    id        INTEGER NOT NULL ,
    name      CHAR(32) NOT NULL ,
    age       INTEGER,
    fecreg    DATETIME YEAR TO SECOND
  ) IN dbs2;
id name       fecreg              partition dbspace

 6 Euan       2019-01-03 00:00:00 dbs2      dbs2
 7 ARON       2018-12-31 00:00:00 dbs2      dbs2

Merge the person_surviving and person_consumed tables into a single table named person_surviving:

Copy
ALTER FRAGMENT ON TABLE person_surviving ATTACH person_consumed AS PARTITION p1 VALUES < DATETIME(2019-01-01 00:00:00) YEAR TO SECOND;

After executing the alter fragment statement, the scheme of the table person_surviving is not vary:

Copy
CREATE TABLE person_surviving
  (
    id        INTEGER NOT NULL ,
    name      CHAR(32) NOT NULL ,
    age       INTEGER,
    fecreg    DATETIME YEAR TO SECOND
  ) FRAGMENT BY RANGE (fecreg) INTERVAL (INTERVAL(1) MONTH(9) TO MONTH) STORE IN (dbs1)
    PARTITION p0 VALUES < DATETIME(2018-01-01 00:00:00) YEAR TO SECOND IN dbs2;
id name       fecreg              partition dbspace

 1 Paul       2017-12-31 00:00:00 p0        dbs2
 2 Alisa      2017-10-20 00:00:00 p0        dbs2
 3 Conall     2018-01-15 00:00:00 sys_p1    dbs1
 4 Duncan     2018-01-23 00:00:00 sys_p1    dbs1
 5 Archie     2019-01-02 00:00:00 sys_p13   dbs1
 6 Euan       2019-01-03 00:00:00 sys_p13   dbs1
 7 ARON       2018-12-31 00:00:00 p1        dbs2

7.5.3 Detach an fragmented table

Example

Scheme of the table before detached:

Copy
CREATE TABLE person
  (
    id        INTEGER NOT NULL ,
    name      CHAR(32) NOT NULL ,
    age       INTEGER
  ) FRAGMENT BY ROUND ROBIN in dbs1 , dbs2;
id name               age partition dbspace

 1 Name 1              10 dbs1      dbs1
 2 Name 2              15 dbs1      dbs1
 3 Name 3              12 dbs1      dbs1
 4 Name 4              25 dbs1      dbs1
 5 Name 5              55 dbs1      dbs1
 6 Name 6              22 dbs1      dbs1
 7 Name 7              17 dbs2      dbs2
 8 Name 8              45 dbs2      dbs2
 9 Name 9              29 dbs2      dbs2

Detach the fragment stored in the dbspace db2 from the table:

Copy
ALTER FRAGMENT ON TABLE person DETACH dbs2 person_detached;

After executing the alter fragment statement, the scheme of the table person is as follows:

Copy
CREATE TABLE person
  (
    id        INTEGER NOT NULL ,
    name      CHAR(32) NOT NULL ,
    age       INTEGER
  ) IN dbs1;
id name               age partition dbspace

 1 Name 1              10 dbs1      dbs1
 2 Name 2              15 dbs1      dbs1
 3 Name 3              12 dbs1      dbs1
 4 Name 4              25 dbs1      dbs1
 5 Name 5              55 dbs1      dbs1
 6 Name 6              22 dbs1      dbs1

After executing the alter fragment statement, a new table created named person_detached with the follow scheme:

Copy
CREATE TABLE person_detached
  (
    id        INTEGER NOT NULL ,
    name      CHAR(32) NOT NULL ,
    age       INTEGER
  ) IN dbs2;
id name               age partition dbspace

 7 Name 7              17 dbs2      dbs2
 8 Name 8              45 dbs2      dbs2
 9 Name 9              29 dbs2      dbs2

8 Rolling Window Tables

The rolling windows feature is intended to minimize the maintenance overhead of removing data that tends to accumulate and then not be needed after some period of time.

Rolling window table purge allows for the management of Informix table space allocation without ever having the need to take explicit action.

By extending the interval table fragmentation strategy to automatically detach and optionally afterward drop table fragments that are no longer needed (based on predetermined criteria such as never allowing a table to exceed a certain size or specific number of fragments).

The capabilities that are new to this feature (as highlighted) are expressed in the Interval Fragment Clause as shown below:

Copy
Interval Fragment Clause
|--INTERVAL--(--+---------------+--)--+---------------------------+-->
 '-intvl_valexpr-' '-| Rolling Window clause |-'
>--+-------------------------------------------+---------------->
 | .-,-------. |
 | V | |
 '-+-------+--IN--(--+---dbspace-+------+--)-'
 '-STORE-' '-dbspace_fun--( )-'
 .-,-----------------------------------------------------------.
 V |
>----PARTITION--partition--+-VALUES < range_expr-+--IN--dbspace-+--|
 | (1) |
 '-------VALUES IS NULL-'
 
Rolling Window clause

|--+-ROLLING--(--quantity--FRAGMENTS--)--+---------------------------+-+-->
   |                                     '-LIMIT TO--max_size--units-' |
   '-LIMIT TO--max_size--units-----------------------------------------'
                  .-INTERVAL FIRST----.
>----+-DETACH--+--+-+-----+-----------+-------------------------|
     '-DISCARD-'  | '-ANY-'           |
                  '-+---------------+-'
                    '-INTERVAL ONLY-'
  • ROLLING clause:
    • Used to specify the number of active interval fragments.
    • When interval fragments exceed the set value (that is when a new one is created), the interval fragment holding the lowest set of values will be detached.
  • LIMIT clause:
    • Specifies the maximum size of the table
    • When limit exceeded, fragments holding the lowest value will be detached until space used is below limit
    • The comparison is done against the overall size (data and indices pages allocated) of the table
    • Both interval and initial range fragments could be detached depending on the action specified
  • DETACH | DISCARD clause:
    • Decides the fate of affected fragments
    • DISCARD will eliminate the fragment for good
    • DETACH will preserve the data by detaching the fragment in a new table
    • Applications can detect detached fragments and archive their contents into different tables, databases, aggregate it, etc.
    • The actual detach/discard is done through the DBscheduler
  • ANY | INTERVAL FIRST | INTERVAL ONLY:
    • If the ANY keyword immediately follows the DETACH or the DISCARD keyword, a range or interval fragment will be detached, starting with the fragment having the lowest sysfragments.evalpos value.
    • If the INTERVAL ONLY keywords are specified, only interval fragments are detached, again starting with the fragment having the lowest sysfragments.evalpos value, a value correlated with the age of the rows in the fragment.
    • If the INTERVAL FIRST keywords immediately follow the DETACH or DISCARD keyword, the database server detaches interval fragments first, starting with the lowest sysfragments.evalpos value, until the allocated storage size requirement has been met. If after having detached all interval fragments, the storage size limit has not been met, the database server, as a safety measure, detaches range fragments, starting with the lowest.
    • Default is INTERVAL FIRST
    • Range fragments will be detached but preserved empty

8.1 Enforcing a purge policy

A rolling window table's purge policy is not immediately enforced when the total allocated storage size or the total number of interval fragments exceeds the limit that the Rolling Window clause specifies.

Purge policies are designed to be enforced daily as a Scheduler task ' purge_tables' at a time when the required DETACH and ATTACH operations on fragments of the rolling window table are unlikely to conflict with access attempts by concurrent users.

Detaching or dropping fragments also can be done manually, executing function syspurge() from the database from which the fragments should be dropped detached.