By Franck Pachot

.
On Twitter, Ludovico Caldara mentioned the #licensing #pitfall when using the Online Partition Move with Basic Compression. Those two features are available in Enterprise Edition without additional option, but when used together (moving online a compressed partition) they enable the usage of Advance Compression Option:


And there was a qustion about detection of this feature. I’ll show how this is detected. Basically, the ALTER TABLE MOVE PARTITION sets the “fragment was compressed online” flag in TABPART$ or TABSUBPART$ when the segment was compressed during the online move.

I create a partitioned table:


SQL> create table SCOTT.DEMO(id,x) partition by hash(id) partitions 2 as select rownum,lpad('x',100,'x') from xmltable('1 to 1000');

Table created.

I set basic compression, which does not compress anything yet but only for future direct loads:


SQL> alter table SCOTT.DEMO modify partition for (42) compress;

Table altered.

I move without the ‘online’ keyword:


SQL> alter table SCOTT.DEMO move partition for (42);

Table altered.

This does not enable the online compression flag (which is 0x2000000):


SQL> select obj#,dataobj#,part#,flags,to_char(flags,'FMXXXXXXXXXXXXX') from SYS.TABPART$ where obj# in ( select object_id from dba_objects where owner='SCOTT' and objec
t_name='DEMO');

      OBJ#   DATAOBJ#      PART#      FLAGS TO_CHAR(FLAGS,
---------- ---------- ---------- ---------- --------------
     75608      75608          1          0 0
     75609      75610          2         18 12

The 0x12 is about the presence of statistics (the MOVE does online statistics gathering in 12c).


SQL> exec sys.dbms_feature_usage_internal.exec_db_usage_sampling(sysdate)

PL/SQL procedure successfully completed.

SQL> select name,detected_usages,currently_used,feature_info from dba_feature_usage_statistics where name='Segment Maintenance Online Compress';

NAME                                     DETECTED_USAGES CURRE FEATURE_INFO
---------------------------------------- --------------- ----- --------------------------------------------------------------------------------
Segment Maintenance Online Compress                    0 FALSE

Online Move of compressed partition

Now moving online this compressed segment:


SQL> alter table SCOTT.DEMO move partition for (42) online;

Table altered.

This has enabled the 0x2000000 flag:


SQL> select obj#,dataobj#,part#,flags,to_char(flags,'FMXXXXXXXXXXXXX') from SYS.TABPART$ where obj# in ( select object_id from dba_objects where owner='SCOTT' and objec
t_name='DEMO');

      OBJ#   DATAOBJ#      PART#      FLAGS TO_CHAR(FLAGS,
---------- ---------- ---------- ---------- --------------
     75608      75608          1          0 0
     75611      75611          2   33554450 2000012

And, of course, is logged by the feature usage detection:


SQL> exec sys.dbms_feature_usage_internal.exec_db_usage_sampling(sysdate)

PL/SQL procedure successfully completed.

SQL> select name,detected_usages,currently_used,feature_info from dba_feature_usage_statistics where name='Segment Maintenance Online Compress';

NAME                                     DETECTED_USAGES CURRE FEATURE_INFO
---------------------------------------- --------------- ----- --------------------------------------------------------------------------------
Segment Maintenance Online Compress                    1 FALSE Partition Obj# list: 75611:

The FEATURE_INFO mentions the object_id for the concerned partitions (for the last detection only).

No Compress

The only way I know to disable this flag is to uncompress the partition, and this can be done online:


SQL> alter table SCOTT.DEMO move partition for (42) nocompress online;

Table altered.

SQL> select obj#,dataobj#,part#,flags,to_char(flags,'FMXXXXXXXXXXXXX') from SYS.TABPART$ where obj# in ( select object_id from dba_objects where owner='SCOTT' and object_name='DEMO');

      OBJ#   DATAOBJ#      PART#      FLAGS TO_CHAR(FLAGS,
---------- ---------- ---------- ---------- --------------
     75608      75608          1          0 0
     75618      75618          2         18 12

DBMS_REDEFINITION

As a workaround, DBMS_REDEFINITION does not use the Advanced Compression Option. For example, this does not enable any flag:


SYS@CDB$ROOT>
SYS@CDB$ROOT> alter table SCOTT.DEMO rename partition for (24) to PART1;

Table altered.

SYS@CDB$ROOT> create table SCOTT.DEMO_X for exchange with table SCOTT.DEMO;

Table created.

SYS@CDB$ROOT> alter table SCOTT.DEMO_X compress;

Table altered.

SYS@CDB$ROOT> exec dbms_redefinition.start_redef_table(uname=>'SCOTT',orig_table=>'DEMO',int_table=>'DEMO_X',part_name=>'PART1',options_flag=>dbms_redefinition.cons_use
_rowid);

PL/SQL procedure successfully completed.

SYS@CDB$ROOT> exec dbms_redefinition.finish_redef_table(uname=>'SCOTT',orig_table=>'DEMO',int_table=>'DEMO_X',part_name=>'PART1');

PL/SQL procedure successfully completed.

SYS@CDB$ROOT> drop table SCOTT.DEMO_X;                                                                                                                        
Table dropped.

But of course, the difference is that only the blocks that are direct-path inserted into the interim table are compressed. Not the online modifications.

Only for partitions?

As far as I know, this is detected only for partitions and subpartitions, the online partition move operation which came in 12cR1. Since 12cR2 we can also move online a non-partitioned table and this, as far as I know, is not detected by dba_feature_usage_statistics. But don’t count on this as this may be considered as a bug which may be fixed one day.