Updated on 2024-05-07 GMT+08:00

Table Design

Generally, well-designed table must comply with the following rules:

  • Reduce the amount of data to be scanned. You can use the pruning mechanism of a partitioned table.
  • Minimize random I/Os. Through clustering, you can sequentially store hot data, converting random I/O to sequential I/O to reduce the cost of I/O scanning.

Selecting a Partitioning Mode

Comply with the following rules to partition a table containing a large amount of data:

  • Create partitions on columns that indicate certain ranges, such as dates and regions.
  • A partition name should show the data characteristics of a partition. For example, its format can be Keyword+Range characteristics.
  • Set the upper limit of a partition to MAXVALUE to prevent data overflow.
    Table 1 Table partitioning modes and scenarios

    Partitioning Mode

    Description

    Range

    Table data is partitioned by range.

    Interval

    Table data is partitioned by range. If the data exceeds the range, a new partition is automatically created based on the interval.

    List

    Table data is partitioned by a specified column based on a specific value.

    Hash

    Table data is partitioned by hash.

    The example of defining a partitioned table is as follows:
     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    15
    16
    17
    18
    19
    20
    21
    22
    23
    24
    25
    26
    27
    28
    29
    30
    31
    32
    33
    34
    35
    36
    37
    38
    39
    40
    41
    42
    43
    44
    45
    46
    47
    48
    49
    50
    51
    52
    53
    54
    55
    -- Create a range partitioned table.
    CREATE TABLE staffS_p1
    (
      staff_ID       NUMBER(6) not null,
      FIRST_NAME     VARCHAR2(20),
      LAST_NAME      VARCHAR2(25),
      EMAIL          VARCHAR2(25),
      PHONE_NUMBER   VARCHAR2(20),
      HIRE_DATE      DATE,
      employment_ID  VARCHAR2(10),
      SALARY         NUMBER(8,2),
      COMMISSION_PCT NUMBER(4,2),
      MANAGER_ID     NUMBER(6),
      section_ID     NUMBER(4)
    )
    PARTITION BY RANGE (HIRE_DATE)
    ( 
       PARTITION HIRE_19950501 VALUES LESS THAN ('1995-05-01 00:00:00'),
       PARTITION HIRE_19950502 VALUES LESS THAN ('1995-05-02 00:00:00'),
       PARTITION HIRE_maxvalue VALUES LESS THAN (MAXVALUE)
    );
    
    -- Create an interval partitioned table. The table has two initial partitions. When data that is not in the partition range is inserted, another partition is automatically added.
    CREATE TABLE sales
    (prod_id NUMBER(6),
     cust_id NUMBER,
     time_id DATE,
     channel_id CHAR(1),
     promo_id NUMBER(6),
     quantity_sold NUMBER(3),
     amount_sold NUMBER(10,2)
    )
    PARTITION BY RANGE (time_id)
    INTERVAL('1 day')
    ( PARTITION p1 VALUES LESS THAN ('2019-02-01 00:00:00'),
      PARTITION p2 VALUES LESS THAN ('2019-02-02 00:00:00')
    );
    
    -- Create a list partitioned table.
    CREATE TABLE test_list (col1 int, col2 int)
    partition by list(col1)
    (
    partition p1 values (2000),
    partition p2 values (3000),
    partition p3 values (4000),
    partition p4 values (5000)
    );
    
    -- Create a hash partitioned table.
    CREATE TABLE test_hash (col1 int, col2 int)
    partition by hash(col1)
    (
    partition p1,
    partition p2
    );
    

    For details about the table partition syntax, see CREATE TABLE PARTITION.