The following information provides a general rule for estimating the size of a database:
After reading these sections, you should read "Designing and Choosing Table Spaces".
Information is not provided for the space required by such things as:
Information such as row size and structure is precise. However, multiplication factors for file overhead because of disk fragmentation, free space, and variable length columns will vary in your own database since there is such a wide range of possibilities for the column types and lengths of rows in a database. After initially estimating your database size, create a test database and populate it with representative data. You will then find a multiplication factor that is more accurate for your own particular database design.
When a database is initially created, system catalog tables are created. The system tables will grow as database objects and privileges are added to the database. Initially, they use approximately 1600 KB of disk space.
The amount of space allocated for the catalog tables depends on the type of table space and the extent size for the table space containing the catalog tables. For example, if a DMS table space with an extent size of 32 is used, the catalog table space will initially be allocated 20MB of space. For more information, see "Designing and Choosing Table Spaces".
Note: | For databases with multiple partitions, the catalog tables only reside on the partition where the CREATE DATABASE was issued. Disk space for the catalog tables is only required for that partition. |
Table data is stored on 4KB pages. Each page contains 76 bytes of overhead for the database manager. This leaves 4020 bytes to hold user data (or rows), although no row can exceed 4005 bytes in length. A row will not span multiple pages.
Note that the table data pages do not contain the data for columns defined with LONG VARCHAR, LONG VARGRAPHIC, BLOB, CLOB, or DBCLOB data types. The rows in a table data page do, however, contain a descriptor of these columns. (See "Long Field Data" and "Large Object (LOB) Data" for information about estimating the space required for the table objects that will contain the data stored using these data types.)
Rows are inserted into the table in a first-fit order. The file is searched (using a free space map) for the first available space that is large enough to hold the new row. When a row is updated, it is updated in place unless there is insufficient room left on the 4KB page to contain it. If this is the case, a record is created in the original row location which points to the new location in the table file of the updated row.
See "Long Field Data" and "Large Object (LOB) Data" for information about how LONG VARCHAR, LONG VARGRAPHIC, BLOB, CLOB and DBCLOB data is stored and for estimating the space required to store these types of columns.
For each user table in the database, the number of pages can be estimated by calculating:
ROUND DOWN(4020/(average row size + 8)) = records_per_pageThen use records_per_page with:
(number_of_records/records_per_page) * 1.1 = number_of_pages
The average row size is the sum of the average column sizes. For information on the size of each column, see CREATE TABLE in the SQL Reference.
The factor of "1.1" is for overhead such as page overhead and free space.
If a table has LONG VARCHAR or LONG VARGRAPHIC data, in addition to the byte count of 20 for the LONG VARCHAR or LONG VARGRAPHIC descriptor (in the table row), the data itself must be stored. Long field data is stored in a separate table object which is structured differently from the other data types (see "User Table Data" and "Large Object (LOB) Data").
Data is stored in 32KB areas that are broken up into segments whose sizes are "powers of two" times 512 bytes. (Hence these segments can be 512 bytes, 1024 bytes, 2048 bytes, and so on, up to 32,700 bytes.)
Each of these data types is stored in a fashion that enables free space to be reclaimed easily. Allocation and free space information is stored in 4KB allocation pages, which appear infrequently throughout the object.
The amount of unused space in the object depends on the size of the long field data and whether this size is relatively constant across all occurrences of the data. For data entries larger than 255 bytes, this unused space can be up to 50 percent of the size of the long field data.
If character data is less than 4KB in length, and it fits in the record with the rest of the data, the CHAR, GRAPHIC, VARCHAR, or VARGRAPHIC data types should be used instead of LONG VARCHAR or LONG VARGRAPHIC.
If a table has BLOB, CLOB, or DBCLOB data, in addition to the byte count (between 72 and 312 bytes) for the BLOB, CLOB, or DBCLOB descriptor (in the table row), the data itself must be stored. This data is stored in two separate table objects that are structured differently than other data types (see "User Table Data" and "Long Field Data").
To estimate the space required by large object data, you need to consider the two table objects used to store data defined with these data types:
Data is stored in 64MB areas that are broken up into segments whose sizes are "powers of two" times 1024 bytes. (Hence these segments can be 1024 bytes, 2048 bytes, 4096 bytes, and so on, up to 64MB.)
To reduce the amount of disk space used by the LOB data, you can use the COMPACT parameter on the lob-options-clause on the CREATE TABLE and ALTER TABLE statements. The COMPACT option minimizes the amount of disk space required by allowing the LOB data to be split into smaller segments so that it will use the smallest amount of space possible. This does not involve data compression but is simply using the minimum amount of space to the nearest 1KB boundary. Without the COMPACT option, there is no attempt to reduce the space used to the nearest 1KB boundary. Appending to LOB values stored using the COMPACT option may result in slower performance compared to appending LOB values for which the COMPACT option is not specified.
The amount of free space contained in LOB data objects will be influenced by the amount of update and delete activity, as well as the size of the LOB values being inserted.
Allocation and free space information is stored in 4KB allocation pages separated from the actual data. The number of these 4KB pages is dependent on the amount of data, including unused space, allocated for the large object data. The overhead is calculated as follows: one 4KB pages for every 64GB plus one 4KB page for every 8MB.
If character data is less than 4KB in length, and it fits in the record with the rest of the data, the CHAR, GRAPHIC, VARCHAR, or VARGRAPHIC data types should be used instead of BLOB, CLOB or DBCLOB.
For each index, the space needed can be estimated as:
(average index key size + 8) * number of rows * 2where:
Note: | For every column that allows nulls, add one extra byte for the null indicator. |
Temporary space is required when creating the index. The maximum amount of temporary space required during index creation can be estimated as:
(average index key size + 8) * number of rows * 3.2
where the factor of 3.2 is for index overhead as well as space required for the sorting needed to create the index.
Note: | In the case of non-unique indexes, only four (4) bytes are required to store duplicate key entries. The estimates shown above assume no duplicates. The space required to store an index may be over-estimated by the formula shown above. |
The following two calculations can be used to estimate the number of leaf pages. The results are not guaranteed. The results are only an estimate, and the accuracy depends largely on how well the averages used reflect the actual data.
Note: | For SMS, the minimum space is 12KB. For DMS, the minimum is an extent. |
The average number of keys per page is roughly:
(.9 * (3997 - (M*2))) * (D + 1) ------------------------------- K + 6 + (4 * D)where:
Remember that minimumKeySize and averageKeysize must have an extra 1 byte for each nullable key part.
The number of pages (including non-leaf pages) can be roughly calculated as follows:
P = number of pages = 0 initially X = total number of pages N = average number of keys per page Y = X/N While (Y > 1) { P = P + Y Y = Y / N } P = P + P/16000 + 3
Finally, the amount of space for the index is P * 4096.
For DMS table spaces, add together the total sizes for all indexes on a table and round up to a multiple of the extent size for the table space where the index resides.