Compression Methods on Exadata: Compression on partition tables – Part 4 of 6

partitiondataIn the part 1, part 2, part 3 of the blog series, I show the examples to create compress tables using CREATE TABLE and ALTER TABLE MOVE and how to improve the compression performance using parallelism. For big database, partition table is quite common. This post shows how partition table behaves for different compression methods. There is a nice thing about partition table is that you can compress certain partitions while leave other partition uncompressed. This is very useful feature as you might need to compress historical data and only keep the current partition uncompressed. Printer manufacturer Brother has an interesting newspaper ads for its USP product shown above. Obviously this guy needs a better partition strategy as well as compression approaches to save his files digitally.

First let’s create a partition table. I made a slight change in the create table script from part 1.

CREATE TABLE PARTAB
(
    ID NUMBER,
    OWNER VARCHAR2(30) NOT NULL ENABLE,
    OBJECT_NAME VARCHAR2(30) NOT NULL ENABLE,
    SUBOBJECT_NAME VARCHAR2(30),
    OBJECT_ID NUMBER NOT NULL ENABLE,
    DATA_OBJECT_ID NUMBER,
    OBJECT_TYPE VARCHAR2(19),
    CREATED DATE NOT NULL ENABLE,
    LAST_DDL_TIME DATE NOT NULL ENABLE,
    TIMESTAMP VARCHAR2(19),
    STATUS VARCHAR2(7),
    TEMPORARY VARCHAR2(1),
    GENERATED VARCHAR2(1),
    SECONDARY VARCHAR2(1),
    NAMESPACE NUMBER NOT NULL ENABLE,
    EDITION_NAME VARCHAR2(30)
)
PARTITION BY RANGE (OBJECT_ID)
    (PARTITION P1 values less than (1500),
    PARTITION P2 values less than (4000),
    PARTITION P3 values less than (6000),
    PARTITION P4 values less than (maxvalue)
    );

Then, populate some data with 10 million rows in total.

declare
    l_cnt  number;
    l_rows number := 10000000;
begin
    insert /*+ append */
    into partab
    select rownum, a.*
      from all_objects a;
    l_cnt := sql%rowcount;
    commit;

    while (l_cnt < l_rows)
    loop
        insert /*+ APPEND */ into partab
        select rownum+l_cnt,
               OWNER, OBJECT_NAME, SUBOBJECT_NAME,
               OBJECT_ID, DATA_OBJECT_ID,
               OBJECT_TYPE, CREATED, LAST_DDL_TIME,
               TIMESTAMP, STATUS, TEMPORARY,
               GENERATED, SECONDARY, NAMESPACE, EDITION_NAME
          from partab
         where rownum <= l_rows-l_cnt;         l_cnt := l_cnt + sql%rowcount;         commit;     end loop; end; / 

Check out the row count and table size.

 WZHOU@dbm1> select count(*) from partab;

  COUNT(*)
----------
  10000000

Elapsed: 00:00:07.43

WZHOU@dbm1> select count(*) from partab partition(p1);

  COUNT(*)
----------
   1364992

Elapsed: 00:00:00.08

WZHOU@dbm1> select count(*) from partab partition(p2);

  COUNT(*)
----------
   2560000

Elapsed: 00:00:00.15

WZHOU@dbm1> select count(*) from partab partition(p3);

  COUNT(*)
----------
   1445504

Elapsed: 00:00:00.08

WZHOU@dbm1> select count(*) from partab partition(p4);

  COUNT(*)
----------
   4629504

Elapsed: 00:00:00.27

Before doing the compression work, let me check out the table size and partition size. You can find part_size.sql from the Script page. This script is also one of the Enkitec scripts I use frequently.

WZHOU@dbm1> @table_size
Enter value for owner: WZHOU
Enter value for table_name: PARTAB
Enter value for type:

OWNER  SEGMENT_NAME TYPE             TOTALSIZE_MEGS TABLESPACE_NAME
------ ------------ ---------------- -------------- ------------------------------
WZHOU        PARTAB TABLE PARTITION       1,112.0   USERS
                                     --------------
sum                                       1,112.0

WZHOU@dbm1> @part_size
Enter value for owner: WZHOU
Enter value for table_name: PARTAB
Enter value for partition_name:
Enter value for type:

OWNER  SEGMENT_NAME PARTITION_NAME TYPE            TOTALSIZE_MEGS TABLESPACE_NAME
------ ------------ -------------- --------------- -------------- ---------------
WZHOU  PARTAB             P1       TABLE PARTITION       152.0    USERS
WZHOU  PARTAB             P2       TABLE PARTITION       280.0    USERS
WZHOU  PARTAB             P3       TABLE PARTITION       152.0    USERS
WZHOU  PARTAB             P4       TABLE PARTITION       528.0    USERS
                                                   --------------
sum                                                    1,112.0

Right now, let me start with the Basic compression.

Basic Compression

WZHOU@dbm1> ALTER TABLE partab MOVE partition p4 COMPRESS;

Table altered.

Elapsed: 00:00:14.00

WZHOU@dbm1> select table_owner,table_name,partition_name,compress_for from DBA_TAB_PARTITIONS
    where table_name = 'PARTAB' and partition_name='P4';

TABLE_OWNER TABLE_NAME PARTITION_NAME COMPRESS_FOR
----------- ---------- -------------- ------------
WZHOU       PARTAB     P4             BASIC

WZHOU@dbm1> @part_size
Enter value for owner: WZHOU
Enter value for table_name: PARTAB
Enter value for partition_name: P4
Enter value for type:

OWNER  SEGMENT_NAME PARTITION_NAME TYPE            TOTALSIZE_MEGS TABLESPACE_NAME
------ ------------ -------------- --------------- -------------- ---------------
WZHOU  PARTAB             P4       TABLE PARTITION       192.0    USERS
                                                   --------------
sum                                                      192.0

There is little change we need to make before we proceed to the next test. We need to restore this partition to the non-compression stage by using nocompress keyword.

OLTP Compression

WZHOU@dbm1> ALTER TABLE partab MOVE partition p4 nocompress;

Table altered.

Elapsed: 00:00:05.99

WZHOU@dbm1> ALTER TABLE partab MOVE partition p4 compress for oltp;

Table altered.

Elapsed: 00:00:14.22
WZHOU@dbm1> select table_owner,table_name,partition_name,compress_for from DBA_TAB_PARTITIONS     where table_name = 'PARTAB' and partition_name='P4';

TABLE_OWNER TABLE_NAME PARTITION_NAME COMPRESS_FOR
----------- ---------- -------------- ------------
WZHOU       PARTAB     P4             OLTP

Elapsed: 00:00:00.01

WZHOU@dbm1> @part_size
Enter value for owner: WZHOU
Enter value for table_name: PARTAB
Enter value for partition_name: P4
Enter value for type:

OWNER  SEGMENT_NAME PARTITION_NAME TYPE            TOTALSIZE_MEGS TABLESPACE_NAME
------ ------------ -------------- --------------- -------------- ---------------
WZHOU  PARTAB             P4       TABLE PARTITION       192.0    USERS
                                                   --------------
sum                                                      192.0

Query Low Compression

WZHOU@dbm1> ALTER TABLE partab MOVE partition p4 nocompress;

Table altered.

Elapsed: 00:00:06.01
WZHOU@dbm1> ALTER TABLE partab MOVE partition p4 compress for query low;

Table altered.

Elapsed: 00:00:06.83
WZHOU@dbm1> select table_owner,table_name,partition_name,compress_for from DBA_TAB_PARTITIONS
    where table_name = 'PARTAB' and partition_name='P4';

TABLE_OWNER TABLE_NAME PARTITION_NAME COMPRESS_FOR
----------- ---------- -------------- ------------
WZHOU       PARTAB     P4             QUERY LOW

Elapsed: 00:00:00.01

WZHOU@dbm1> @part_size
Enter value for owner: WZHOU
Enter value for table_name: PARTAB
Enter value for partition_name: P4
Enter value for type:

OWNER  SEGMENT_NAME PARTITION_NAME TYPE            TOTALSIZE_MEGS TABLESPACE_NAME
------ ------------ -------------- --------------- -------------- ---------------
WZHOU  PARTAB             P4       TABLE PARTITION        80.0    USERS
                                                   --------------
sum                                                       80.0

Query High Compression

WZHOU@dbm1> ALTER TABLE partab MOVE partition p4 nocompress;

Table altered.

Elapsed: 00:00:05.26

WZHOU@dbm1> ALTER TABLE partab MOVE partition p4 compress for query high;

Table altered.

Elapsed: 00:00:13.08

WZHOU@dbm1> select table_owner,table_name,partition_name,compress_for from DBA_TAB_PARTITIONS
    where table_name = 'PARTAB' and partition_name='P4';

TABLE_OWNER TABLE_NAME PARTITION_NAME COMPRESS_FOR
----------- ---------- -------------- ------------
WZHOU       PARTAB     P4             QUERY HIGH

Elapsed: 00:00:00.01

WZHOU@dbm1> @part_size
Enter value for owner: WZHOU
Enter value for table_name: PARTAB
Enter value for partition_name: P4
Enter value for type:

OWNER  SEGMENT_NAME PARTITION_NAME TYPE            TOTALSIZE_MEGS TABLESPACE_NAME
------ ------------ -------------- --------------- -------------- ---------------
WZHOU  PARTAB             P4       TABLE PARTITION        32.0    USERS
                                                   --------------
sum                                                       32.0

Archive Low Compression

WZHOU@dbm1> ALTER TABLE partab MOVE partition p4 nocompress;

Table altered.

Elapsed: 00:00:05.09

WZHOU@dbm1> ALTER TABLE partab MOVE partition p4 compress for archive low;

Table altered.

Elapsed: 00:00:13.60

WZHOU@dbm1> select table_owner,table_name,partition_name,compress_for from DBA_TAB_PARTITIONS
  where table_name = 'PARTAB' and partition_name='P4';

TABLE_OWNER TABLE_NAME PARTITION_NAME COMPRESS_FOR
----------- ---------- -------------- ------------
WZHOU       PARTAB     P4             ARCHIVE LOW

Elapsed: 00:00:00.00

WZHOU@dbm1> @part_size
Enter value for owner: WZHOU
Enter value for table_name: PARTAB
Enter value for partition_name: P4
Enter value for type:

OWNER  SEGMENT_NAME PARTITION_NAME TYPE            TOTALSIZE_MEGS TABLESPACE_NAME
------ ------------ -------------- --------------- -------------- ---------------
WZHOU  PARTAB             P4       TABLE PARTITION         32.0   USERS
                                                   --------------
sum                                                        32.0

Archive High Compression

WZHOU@dbm1> ALTER TABLE partab MOVE partition p4 nocompress;

Table altered.

Elapsed: 00:00:04.93

WZHOU@dbm1> ALTER TABLE partab MOVE partition p4 compress for archive high;

Table altered.

Elapsed: 00:01:13.33

WZHOU@dbm1> select table_owner,table_name,partition_name,compress_for from DBA_TAB_PARTITIONS
  where table_name = 'PARTAB' and partition_name='P4';

TABLE_OWNER TABLE_NAME PARTITION_NAME COMPRESS_FOR
----------- ---------- -------------- ------------
WZHOU       PARTAB     P4             ARCHIVE HIGH

Elapsed: 00:00:00.01

WZHOU@dbm1> @part_size
Enter value for owner: WZHOU
Enter value for table_name: PARTAB
Enter value for partition_name: P4
Enter value for type:

OWNER  SEGMENT_NAME PARTITION_NAME TYPE            TOTALSIZE_MEGS TABLESPACE_NAME
------ ------------ -------------- --------------- -------------- ---------------
WZHOU  PARTAB             P4       TABLE PARTITION        24.0    USERS
                                                   --------------
sum                                                       24.0

The timing is quite different from 13 seconds on majority of compression methods to about 73 seconds on Archive High method, about 500% time increase. The compression ratio is similar to what we see in the non-partition table. The partition size drops from 528 MB to about 25~40 MB for most of compression methods.

There is another interest aspect in partition tables is that you can use different compression methods for different partitions. This is useful that allows to compress the recent data in faster methods while very old historical data can use a method with longer processing time, but higher compression ratio. Here is the test to show different compression methods for different partitions.

WZHOU@dbm1> ALTER TABLE partab MOVE partition p1 compress for query low;

Table altered.

Elapsed: 00:00:01.88

WZHOU@dbm1> ALTER TABLE partab MOVE partition p2 compress for query high;

Table altered.

Elapsed: 00:00:05.75

WZHOU@dbm1> ALTER TABLE partab MOVE partition p3 compress for archive low;

Table altered.

Elapsed: 00:00:02.34

WZHOU@dbm1> select table_owner,table_name,partition_name,compress_for from DBA_TAB_PARTITIONS
     where table_name = 'PARTAB';

TABLE_OWNER TABLE_NAME PARTITION_NAME COMPRESS_FOR
----------- ---------- -------------- ------------
WZHOU       PARTAB     P1             QUERY LOW
WZHOU       PARTAB     P2             QUERY HIGH
WZHOU       PARTAB     P3             ARCHIVE LOW
WZHOU       PARTAB     P4             ARCHIVE HIGH

Elapsed: 00:00:00.04

WZHOU@dbm1> @part_size
Enter value for owner: WZHOU
Enter value for table_name: PARTAB
Enter value for partition_name:
Enter value for type:

OWNER  SEGMENT_NAME PARTITION_NAME TYPE            TOTALSIZE_MEGS TABLESPACE_NAME
------ ------------ -------------- --------------- -------------- ---------------
WZHOU  PARTAB             P1       TABLE PARTITION        16.0    USERS
WZHOU  PARTAB             P2       TABLE PARTITION        16.0    USERS
WZHOU  PARTAB             P3       TABLE PARTITION         8.0    USERS
WZHOU  PARTAB             P4       TABLE PARTITION        24.0    USERS
                                                   --------------
sum                                                       64.0

See enough code? In the next part, I am going to go back the basic stuff and discuss the layout of HCC as well as some recommendation when to use and when not to use HCC.

Compression Methods on Exadata: Use parallel to speed up compression – Part 3 of 6

parallalData

In the part 1 and part 2 of the blog series, I show the examples to create compress tables using CREATE TABLE and ALTER TABLE MOVE. For small tables in the example, it might be ok not to use the parallelism. But for big tables, parallelism is highly recommended just like the photos above. You have to have many lines on highway to allow high throughput. I wish adding a new line on highway could be as easy as change DOP in SQL. This post discusses parallelism for the compression methods.

As the command will be similar for different kinds of compression method, I pick one HCC method and test the timing for different DOP values. As QUERY LOW gives a lower compression ratio and is very unlikely I am going to use in production, so QUERY LOW is out. Let’s look at ARCHIVE HIGH, although it can give a much better compression ratio, the processing time is usually several times longer than other HCC methods. Given it could also take a longer time to uncompress the data when we need to move data to non-Exadata environment, I will be very unlikely to use this method in the production unless I really need to save significant amount space. So it leaves with QUERY HIGH and ARCHIVE LOW. Both of them are using ZLIB (gzip) compression algorithm. The timing and compression ratios seem quite close from my experience. So either one of them is fine for my test and I choose QUERY HIGH compression method as the base for our test.

I also increase the size of the test table to 80 million rows.

Build Test Data


WZHOU@dbm1> create table paratab_no_parallel as select * from testcp;

Table created.

Elapsed: 00:00:09.17

WZHOU@dbm1> insert /*+ APPEND */ into paratab_no_parallel select * from paratab_no_parallel;

10000000 rows created.

Elapsed: 00:00:17.32

WZHOU@dbm1> insert /*+ APPEND */ into paratab_no_parallel select * from paratab_no_parallel;
insert /*+ APPEND */ into paratab_no_parallel select * from paratab_no_parallel
                          *
ERROR at line 1:
ORA-12838: cannot read/modify an object after modifying it in parallel

Elapsed: 00:00:00.00

It seems I need to do the commit first before I can do further insert operation.

WZHOU@dbm1> commit;

Commit complete.

Elapsed: 00:00:00.00

WZHOU@dbm1> insert /*+ APPEND */ into paratab_no_parallel select * from paratab_no_parallel;

20000000 rows created.

Elapsed: 00:00:24.68

WZHOU@dbm1> commit;

Commit complete.

Elapsed: 00:00:00.01

WZHOU@dbm1> insert /*+ APPEND */ into paratab_no_parallel select * from paratab_no_parallel;

40000000 rows created.

Elapsed: 00:00:44.70

WZHOU@dbm1> select count(*) from paratab_no_parallel
                     *
ERROR at line 1:
ORA-12838: cannot read/modify an object after modifying it in parallel

Elapsed: 00:00:00.01

WZHOU@dbm1> commit;

Commit complete.

Elapsed: 00:00:00.02

WZHOU@dbm1> select count(*) from paratab_no_parallel;

  COUNT(*)
----------
  80000000

Elapsed: 00:00:34.27

Let’s find out what is the size for this table.

WZHOU@dbm1> @table_size
Enter value for owner: WZHOU
Enter value for table_name: PARATAB%
Enter value for type:

OWNER  SEGMENT_NAME         TYPE    TOTALSIZE_MEGS TABLESPACE_NAME
------ -------------------- ------- -------------- ---------------
WZHOU  PARATAB_NO_PARALLEL  TABLE          8,824.4 USERS
                                       --------------
sum                                        8,824.4

Elapsed: 00:00:00.09

Then create three more similar tables.

WZHOU@dbm1> create table paratab_dop_2 as select * from paratab_no_parallel;

Table created.

Elapsed: 00:01:09.56

WZHOU@dbm1> create table paratab_dop_4 as select * from paratab_no_parallel;

Table created.

Elapsed: 00:01:08.55

WZHOU@dbm1> create table paratab_dop_8 as select * from paratab_no_parallel;

Table created.

Elapsed: 00:01:08.86

Parallel Tests

WZHOU@dbm1> ALTER TABLE paratab_no_parallel MOVE COMPRESS for query high;

Table altered.

Elapsed: 00:03:32.30

WZHOU@dbm1> ALTER TABLE paratab_dop_2 MOVE COMPRESS for query high parallel 2;

Table altered.

Elapsed: 00:01:48.43

WZHOU@dbm1> ALTER TABLE paratab_dop_4 MOVE COMPRESS for query high parallel 4;

Table altered.

Elapsed: 00:00:57.07

WZHOU@dbm1> ALTER TABLE paratab_dop_8 MOVE COMPRESS for query high parallel 8;

Table altered.

Elapsed: 00:00:29.63

WZHOU@dbm1> @table_size
Enter value for owner: WZHOU
Enter value for table_name: PARATAB%
Enter value for type:

OWNER  SEGMENT_NAME         TYPE    TOTALSIZE_MEGS TABLESPACE_NAME
------ -------------------- ------- -------------- ---------------
WZHOU  PARATAB_DOP_2        TABLE           453.3  USERS
WZHOU  PARATAB_DOP_4        TABLE           454.2  USERS
WZHOU  PARATAB_DOP_8        TABLE           456.7  USERS
WZHOU  PARATAB_NO_PARALLEL  TABLE           464.0  USERS
                                    --------------
sum                                       1,828.2

As the DOP increases, the processing time reduces in a linear fashion. The compression time for a 9G table reduces from three and half minutes to less than half minute with DOP of 8. Another interesting part is that the final compression size is slight different with different DOP value.

Compression Methods on Exadata: Create compression table using ALTER TABLE MOVE – Part 2 of 6

moveData
In the last post, it shows the examples to create compression tables using CREATE TABLE clause. In reality, majority of the time, we have existing tables in place and we just need to change it to a compression table. It is important to know when the compression happens. For example, if uses ALTER TABLE … COMPRESS FOR QUERY HIGH command, there is NO change to the existing data in the current table. Only after you uses MOVE keyword to rebuild the segment, it can really do the compression work. As usual, I shows different ways to use MOVE to compress tables as follows. Of course, in my examples, I do not have a plan to use a dolly to move data. But if you have multiple petabyte or even exabyte of data, dolly from a truck may be the faster way to move compared with slow network transfer via WAN across the country.

BASIC Compression:

WZHOU@dbm1> create table movetab_basic as select * from testcp;

Table created.

Elapsed: 00:00:09.38

WZHOU@dbm1> select table_name,logging,compression,compress_for from dba_tables
    where table_name='MOVETAB_BASIC';

TABLE_NAME             LOG COMPRESS COMPRESS_FOR
------------------------------ --- -------- ------------
MOVETAB_BASIC              YES DISABLED

Elapsed: 00:00:00.01

WZHOU@dbm1> ALTER TABLE movetab_basic MOVE COMPRESS;

Table altered.

Elapsed: 00:00:29.78

WZHOU@dbm1> select table_name,logging,compression,compress_for from dba_tables  2  where table_name='MOVETAB_BASIC';

TABLE_NAME             LOG COMPRESS COMPRESS_FOR
------------------------------ --- -------- ------------
MOVETAB_BASIC              YES ENABLED  BASIC

Elapsed: 00:00:00.01

OLTP Compression:


WZHOU@dbm1> create table movetab_oltp as select * from testcp;

Table created.

Elapsed: 00:00:08.30

WZHOU@dbm1> ALTER TABLE movetab_oltp MOVE COMPRESS FOR oltp;

Table altered.

Elapsed: 00:00:29.03

WZHOU@dbm1> select table_name,logging,compression,compress_for from dba_tables
   where table_name='MOVETAB_OLTP';

TABLE_NAME             LOG COMPRESS COMPRESS_FOR
------------------------------ --- -------- ------------
MOVETAB_OLTP               YES ENABLED  OLTP

Elapsed: 00:00:00.00

Query Low Compression:

WZHOU@dbm1> create table movetab_query_low as select * from testcp;

Table created.

Elapsed: 00:00:08.82

WZHOU@dbm1> select table_name,logging,compression,compress_for from dba_tables
    where table_name='MOVETAB_QUERY_LOW';

TABLE_NAME             LOG COMPRESS COMPRESS_FOR
------------------------------ --- -------- ------------
MOVETAB_QUERY_LOW          YES DISABLED

Elapsed: 00:00:00.00

WZHOU@dbm1> ALTER TABLE movetab_query_low MOVE COMPRESS for query low;

Table altered.

Elapsed: 00:00:15.70

WZHOU@dbm1> select table_name,logging,compression,compress_for from dba_tables
    where table_name='MOVETAB_QUERY_LOW';

TABLE_NAME             LOG COMPRESS COMPRESS_FOR
------------------------------ --- -------- ------------
MOVETAB_QUERY_LOW          YES ENABLED  QUERY LOW

Elapsed: 00:00:00.01

Query High Compression:


WZHOU@dbm1> create table movetab_query_high as select * from testcp;

Table created.

Elapsed: 00:00:08.21

WZHOU@dbm1> select table_name,logging,compression,compress_for from dba_tables
  2  where table_name='MOVETAB_QUERY_HIGH';

TABLE_NAME             LOG COMPRESS COMPRESS_FOR
------------------------------ --- -------- ------------
MOVETAB_QUERY_HIGH         YES DISABLED

Elapsed: 00:00:00.00

WZHOU@dbm1> ALTER TABLE movetab_query_high MOVE COMPRESS for query high;

Table altered.

Elapsed: 00:00:27.60

WZHOU@dbm1> select table_name,logging,compression,compress_for from dba_tables
  2  where table_name='MOVETAB_QUERY_HIGH';

TABLE_NAME             LOG COMPRESS COMPRESS_FOR
------------------------------ --- -------- ------------
MOVETAB_QUERY_HIGH         YES ENABLED  QUERY HIGH

Elapsed: 00:00:00.00

Archive Low Compression:


WZHOU@dbm1> create table movetab_archive_low as select * from testcp;

Table created.

Elapsed: 00:00:08.74

WZHOU@dbm1> select table_name,logging,compression,compress_for from dba_tables
  2  where table_name='MOVETAB_ARCHIVE_LOW';

TABLE_NAME             LOG COMPRESS COMPRESS_FOR
------------------------------ --- -------- ------------
MOVETAB_ARCHIVE_LOW        YES DISABLED

Elapsed: 00:00:00.00

WZHOU@dbm1> ALTER TABLE movetab_archive_low MOVE COMPRESS for archive low;

Table altered.

Elapsed: 00:00:28.26

WZHOU@dbm1> select table_name,logging,compression,compress_for from dba_tables
  2  where table_name='MOVETAB_ARCHIVE_LOW';

TABLE_NAME             LOG COMPRESS COMPRESS_FOR
------------------------------ --- -------- ------------
MOVETAB_ARCHIVE_LOW        YES ENABLED  ARCHIVE LOW

Elapsed: 00:00:00.00

Archive High Compression:

WZHOU@dbm1> create table movetab_archive_high as select * from testcp;

Table created.

Elapsed: 00:00:08.23

WZHOU@dbm1> select table_name,logging,compression,compress_for from dba_tables
    where table_name='MOVETAB_ARCHIVE_HIGH';

TABLE_NAME             LOG COMPRESS COMPRESS_FOR
------------------------------ --- -------- ------------
MOVETAB_ARCHIVE_HIGH           YES DISABLED

Elapsed: 00:00:00.00

WZHOU@dbm1> ALTER TABLE movetab_archive_high MOVE COMPRESS for archive high;

Table altered.

Elapsed: 00:02:32.26
WZHOU@dbm1> select table_name,logging,compression,compress_for from dba_tables
    where table_name='MOVETAB_ARCHIVE_HIGH';

TABLE_NAME             LOG COMPRESS COMPRESS_FOR
------------------------------ --- -------- ------------
MOVETAB_ARCHIVE_HIGH           YES ENABLED  ARCHIVE HIGH

Elapsed: 00:00:00.00

Remember from last post, the uncompressed table size is 1,152 MB. You can see the sizes of the tables after compression are quite similar to the approaches using CREATE TABLE in the last post.

WZHOU@dbm1> @table_size
Enter value for owner: WZHOU
Enter value for table_name: MOVE%
Enter value for type:

OWNER   SEGMENT_NAME           TYPE    TOTALSIZE_MEGS TABLESPACE_NAME
------- ------------------------------ ---------- --------------
WZHOU   MOVETAB_ARCHIVE_HIGH   TABLE      48.0 USERS
WZHOU   MOVETAB_ARCHIVE_LOW    TABLE      58.0 USERS
WZHOU   MOVETAB_QUERY_HIGH     TABLE      59.0 USERS
WZHOU   MOVETAB_QUERY_LOW      TABLE     160.0 USERS
WZHOU   MOVETAB_BASIC          TABLE     384.0 USERS
WZHOU   MOVETAB_OLTP           TABLE     424.0 USERS
                                       --------------
sum                                    1,133.0

6 rows selected.

[update 1]
So what’s happened if I need to access this table during the move, can I still do the select or other DML operation against this table during the move? With this question in mind, I did a few tests to see how it behaves during the MOVE operation. Make the Move operation longer, I use ARCHIVE HIGH compression method to see the difference. I also opened 5 more db sessions to do SELECT, INSERT, UPDATE, DELETE and monitor operations.

Session 1:

WZHOU@dbm1> create table movetab_chkop as select * from testcp;
Table created.
Elapsed: 00:00:08.32

Then in the same session, run the compression for archive high. During the compression process, run other operations in different sessions as follows:

ALTER TABLE movetab_chkop MOVE COMPRESS for archive high;

Session 2 (check SELECT):
select id, object_name from movetab_chkop where id = 10;
select count(*) from movetab_chkop;

Session 3 (check INSERT):
insert into movetab_chkop select * from testcp where id = 1;

Session 4 (check UPDATE):
update movetab_chkop set id = 1001 where id = 10000;

Session 5 (check DELETE):
delete from movetab_chkop where id = 5000;

Session 6 (Monitor the other sessions)
run as.sql script to check out the active session.
as.sql

The script to check who is blocking who

select l1.sid, ‘ IS BLOCKING ‘, l2.sid
from v$lock l1, v$lock l2
where l1.block =1 and l2.request > 0
and l1.id1=l2.id1
and l1.id2=l2.id2;

The result are listed as follows:

Session 1 (Do archive high compression)

WZHOU@dbm1> ALTER TABLE movetab_chkop MOVE COMPRESS for archive high;
Table altered.
Elapsed: 00:02:32.15

Session 2 (check SELECT)

WZHOU@dbm1> select id, object_name from movetab_chkop where id = 10;

	ID OBJECT_NAME
---------- ------------------------------
	10 I_OBJ5

Elapsed: 00:00:00.70

WZHOU@dbm1> select count(*) from movetab_chkop;

  COUNT(*)
----------
  10000000

Elapsed: 00:00:00.65

WZHOU@dbm1> select id, object_name from movetab_chkop where id = 10000;

	ID OBJECT_NAME
---------- ------------------------------
     10000 KU$_M_VIEW_SCM_T

Elapsed: 00:00:00.04

WZHOU@dbm1> select id, object_name from movetab_chkop where id = 5000;

	ID OBJECT_NAME
---------- ------------------------------
      5000 UTL_RECOMP_ALL_OBJECTS
Elapsed: 00:00:00.02

Session 3 (check INSERT)

WZHOU@dbm1> insert into movetab_chkop select * from testcp where id = 1;

1 row created.
Elapsed: 00:02:09.70

Session 4 (check UPDATE)

WZHOU@dbm1> update movetab_chkop set id = 1001 where id = 10000;

1 row updated.
Elapsed: 00:02:04.50

Session 5 (check DELETE)

WZHOU@dbm1> delete from movetab_chkop where id = 5000;

1 row deleted.
Elapsed: 00:01:59.17

Session 6 (Monitor the other sessions)

WZHOU@dbm1> @as

  SID	 SERIAL# PROG	    SQL_ID	   CHILD PLAN_HASH_VALUE      EXECS   AVG_ETIME OFF SQL_TEXT
----- ---------- ---------- ------------- ------ --------------- ---------- ----------- --- -----------------------------------------
 1167	     587 sqlplus@en 1vz2hfh9wccwd      0      3566611749	  0	    .00 No  insert into movetab_chkop select * from t
 1945	      15 sqlplus@en 8856nfxk46wv8      0       900447529	  0	    .00 No  delete from movetab_chkop where id = 5000
  976	     669 sqlplus@en 9qta3dvp1jp5f      0       143915756	  0	  67.22 Yes ALTER TABLE movetab_chkop MOVE COMPRESS f
 1751	      15 sqlplus@en b2qff928t8ca7      1      2858995896	  8	    .35 No  select sid, serial#,substr(program,1,19)
 1557	     341 sqlplus@en f23grns86fvmn      0      3466372318	  0	    .01 No  update movetab_chkop set id = 1001 where

Elapsed: 00:00:00.45

WZHOU@dbm1> select l1.sid, ' IS BLOCKING ', l2.sid
  from v$lock l1, v$lock l2
    where l1.block =1 and l2.request > 0
    and l1.id1=l2.id1
        and l1.id2=l2.id2;

  SID 'ISBLOCKING'    SID
----- ------------- -----
  976  IS BLOCKING   1167
  976  IS BLOCKING   1557
  976  IS BLOCKING   1945

Elapsed: 00:00:00.08

After the compression completes, all DML operations are unblocked.

WZHOU@dbm1> @as

  SID	 SERIAL# PROG	    SQL_ID	   CHILD PLAN_HASH_VALUE      EXECS   AVG_ETIME OFF SQL_TEXT
----- ---------- ---------- ------------- ------ --------------- ---------- ----------- --- -----------------------------------------
 1751	      15 sqlplus@en b2qff928t8ca7      1      2858995896	  9	    .36 No  select sid, serial#,substr(program,1,19)

Elapsed: 00:00:00.44

WZHOU@dbm1> select l1.sid, ' IS BLOCKING ', l2.sid
  from v$lock l1, v$lock l2
    where l1.block =1 and l2.request > 0
    and l1.id1=l2.id1
        and l1.id2=l2.id2;

no rows selected

From the above results, we can see the MOVE operation is blocking all DML operations while select operation is not blocked. So if you have a big table to be compressed, there will be a period all DML operations will be blocked during the move.

Compression Methods on Exadata: Create compression table using CREATE TABLE – Part 1 of 6

dataCompression

I have done compression works in the past on Exadata, but never done a benchmark to compare different types of compression methods on Exadata. Of course, I don’t need a tank shown above to do the compression. But you can see the tank does compression very hard.

Let’s start from the basic ones. The default compression is BASIC method, which was introduced before 11g. In 11g, OLTP compression is used. On Exadata, Oracle uses Hybrid Columnar Compression (HCC). It includes compression methods like Query Low, Query High, Archive Low, and Archive High. This is a six part blog series on compression methods on Exadata.

The tests were run on Exadata X3 Eighth Rack. First, let create a test table with 10 million rows. The create table script is based on Tom Kyte’s test case with slight modifications. (http://asktom.oracle.com)

create table testcp
as
select rownum id, a.*
  from all_objects a
 where 1=0;

declare
    l_cnt  number;
    l_rows number := 10000000;
begin
    -- Copy ALL_OBJECTS
    insert /*+ append */
    into testcp
    select rownum, a.*
      from all_objects a;
    l_cnt := sql%rowcount;
    commit;

    -- Generate Rows
    while (l_cnt < l_rows)
    loop
        insert /*+ APPEND */ into testcp
        select rownum+l_cnt,
               OWNER, OBJECT_NAME, SUBOBJECT_NAME,
               OBJECT_ID, DATA_OBJECT_ID,
               OBJECT_TYPE, CREATED, LAST_DDL_TIME,
               TIMESTAMP, STATUS, TEMPORARY,
               GENERATED, SECONDARY, NAMESPACE, EDITION_NAME
          from testcp
         where rownum <= l_rows-l_cnt;         l_cnt := l_cnt + sql%rowcount;         commit;     end loop; end; / 

Let me verify the row count.

 WZHOU@dbm1> select count(*) from testcp;

COUNT(*)
----------
 10000000

My Enkitec colleagues have many nice scripts and I am going to use a few of them in my tests. The complete scripts used here are listed at Script page.

Ok, Let’s look at the size of the testcp table.

WZHOU@dbm1>  @table_size
Enter value for owner: WZHOU
Enter value for table_name: TESTCP
Enter value for type:

OWNER	SEGMENT_NAME	TYPE	     TOTALSIZE_MEGS TABLESPACE_NAME
------- --------------- ------------ -------------- -------------------------
WZHOU	TESTCP          TABLE              1,152.0  USERS
                                         ----------
sum                                        1,152.0

BASIC Compression:

WZHOU@dbm1> create table testcp_basic compress as select * from testcp where 1=2;
Table created.
Elapsed: 00:00:00.36

WZHOU@dbm1> select table_name,logging,compression,compress_for from dba_tables
  2  where table_name='TESTCP_BASIC';

TABLE_NAME		       LOG COMPRESS COMPRESS_FOR
------------------------------ --- -------- ------------
TESTCP_BASIC                   YES ENABLED  BASIC
Elapsed: 00:00:00.02

WZHOU@dbm1> insert /*+ append */ into testcp_basic select * from testcp;
10000000 rows created.
Elapsed: 00:00:28.18

WZHOU@dbm1> commit;
Commit complete.
Elapsed: 00:00:00.00

OLTP Compression:

WZHOU@dbm1> create table testcp_oltp compress for oltp as select * from testcp where 1=2;
Table created.
Elapsed: 00:00:00.33

WZHOU@dbm1> select table_name,logging,compression,compress_for from dba_tables
where table_name='TESTCP_OLTP';
TABLE_NAME		       LOG COMPRESS COMPRESS_FOR
------------------------------ --- -------- ------------
TESTCP_OLTP            YES ENABLED  OLTP
Elapsed: 00:00:00.02

WZHOU@dbm1> insert /*+ append */ into testcp_oltp select * from testcp;
10000000 rows created.
Elapsed: 00:00:28.87

WZHOU@dbm1> commit;
Commit complete.
Elapsed: 00:00:00.01

Exadata Query Low Compression

WZHOU@dbm1> create table testcp_query_low compress for query low as select * from testcp where 1=2;
Table created.
Elapsed: 00:00:00.34

WZHOU@dbm1> select table_name,logging,compression,compress_for from dba_tables
where table_name='TESTCP_QUERY_LOW';
TABLE_NAME             LOG COMPRESS COMPRESS_FOR
------------------------------ --- -------- ------------
TESTCP_QUERY_LOW       YES ENABLED  QUERY LOW
Elapsed: 00:00:00.02

WZHOU@dbm1> insert /*+ append */ into testcp_query_low select * from testcp;
10000000 rows created.
Elapsed: 00:00:15.41

WZHOU@dbm1> commit;
Commit complete.
Elapsed: 00:00:00.01

Exadata Query High Compression

WZHOU@dbm1> create table testcp_query_high compress for query high as select * from testcp where 1=2;
Table created.
Elapsed: 00:00:00.34

WZHOU@dbm1> select table_name,logging,compression,compress_for from dba_tables
    where table_name='TESTCP_QUERY_HIGH';

TABLE_NAME             LOG COMPRESS COMPRESS_FOR
------------------------------ --- -------- ------------
TESTCP_QUERY_HIGH      YES ENABLED  QUERY HIGH
Elapsed: 00:00:00.02

WZHOU@dbm1> insert /*+ append */ into testcp_query_high select * from testcp;
10000000 rows created.
Elapsed: 00:00:27.59

WZHOU@dbm1> commit;
Commit complete.
Elapsed: 00:00:00.00

Exadata Archive Low Compression

WZHOU@dbm1> create table testcp_archive_low compress for archive low as select * from testcp where 1=2;
Table created.
Elapsed: 00:00:00.34

WZHOU@dbm1> select table_name,logging,compression,compress_for from dba_tables
    where table_name='TESTCP_ARCHIVE_LOW';

TABLE_NAME             LOG COMPRESS COMPRESS_FOR
------------------------------ --- -------- ------------
TESTCP_ARCHIVE_LOW     YES ENABLED  ARCHIVE LOW
Elapsed: 00:00:00.02

WZHOU@dbm1> insert /*+ append */ into testcp_archive_low select * from testcp;
10000000 rows created.
Elapsed: 00:00:28.97

WZHOU@dbm1> commit;
Commit complete.
Elapsed: 00:00:00.01

Exadata Archive High Compression

WZHOU@dbm1> create table testcp_archive_high compress for archive high as select * from testcp where 1=2;
Table created.
Elapsed: 00:00:00.34

WZHOU@dbm1> select table_name,logging,compression,compress_for from dba_tables
    where table_name='TESTCP_ARCHIVE_HIGH';

TABLE_NAME             LOG COMPRESS COMPRESS_FOR
------------------------------ --- -------- ------------
TESTCP_ARCHIVE_HIGH        YES ENABLED  ARCHIVE HIGH
Elapsed: 00:00:00.02

WZHOU@dbm1> insert /*+ append */ into testcp_archive_high select * from testcp;
10000000 rows created.
Elapsed: 00:02:04.72

WZHOU@dbm1> commit;
Commit complete.
Elapsed: 00:00:00.01

So far, we have created six different compression tables. Let’s look at the table size for each of them.

WZHOU@dbm1> @table_size
Enter value for owner: WZHOU
Enter value for table_name: TESTCP%
Enter value for type:

OWNER  SEGMENT_NAME         TYPE    TOTALSIZE_MEGS TABLESPACE_NAME
------ -------------------- ------- -------------- ---------------
WZHOU  TESTCP_QUERY_HIGH    TABLE            59.0 USERS
WZHOU  TESTCP_ARCHIVE_HIGH  TABLE            59.0 USERS
WZHOU  TESTCP_ARCHIVE_LOW   TABLE            59.0 USERS
WZHOU  TESTCP_QUERY_LOW     TABLE           161.0 USERS
WZHOU  TESTCP_BASIC         TABLE           384.0 USERS
WZHOU  TESTCP_OLTP          TABLE           424.0 USERS
WZHOU  TESTCP               TABLE         1,152.0 USERS
                                       --------------
sum                                       2,298.0

7 rows selected.

It’s pretty amazing to see Exadata HCC compressions can get 10~20 compression ratio. From the timing perspective, only Archive High takes three times more than other compression methods.