What is supplemental
logging?
Redo
log files are generally used for instance recovery and media recovery. The data
required for instance recovery and media recovery is automatically recorded in
the redo log files. However a redo log based application may require that the
additional columns need to be logged into redo log files. The process of adding
these additional columns into redo log files is called supplemental logging.
Supplemental
logging is not the default behavior of oracle database. It has to be enabled
manually after the database is created. You can enable the supplemental logging
at two levels
- DATABASE LEVEL
- TABLE LEVEL
Why is supplemental logging needed?
When a
particular column is updated at the source database table for a set of rows,
the values in the column or columns are logged by default. When these values
are moved to the destination side, to which rows does Oracle apply them, or how
does Oracle identify the rows to be updated? Supplemental logging provides the
answers to these questions.
What is the use of
supplemental logging in replication?
Supplemental
logging places additional column data into the redo log file whenever an UPDATE
operation is performed. At the least, minimal database-level supplemental
logging must be enabled for any Change Data Capture source database.
When
Supplemental Logging is enabled, either some selected columns or all columns
are specified for extra logging. They are called a supplemental log
group and consist of nothing but a set of additional columns that are
being logged.
When
the supplemental logging is active on a database, the redo logs contain other
columns from tables to uniquely identify a row. If the table has a primary key
or unique index defined, the only columns involved in the primary key or unique
index will be registered in the redo logs along with the actual column(s) that
has changed.
If the
table does not have any primary keys or unique index defined, Oracle will write
all scalar columns from the table to identify the row. This may significantly
increase the size of redo logs and will impact the log apply services on the
logical standby site.
Depending
on the set of additional columns logged there are two types of supplemental log
groups:
- Unconditional
supplemental log group
- Conditional
supplemental log group
1. UNCONDITIONAL
SUPPLEMENTAL LOG GROUP:
The
before-images of specified columns are logged any time a row is updated,
regardless of whether the update affected any of the specified columns. This
can be referred to as an ALWAYS log group.
2. CONDITIONAL
SUPPLEMENTAL LOG GROUP:
The
before-images of all specified columns are logged only if at least one of the
columns in the log group is updated.
DATABASE LEVEL SUPPLEMENTAL LOGGING
How to
check supplemental logging is enabled or not?
SQL> SELECT supplemental_log_data_min FROM
v$database;
How to
enable supplemental logging at database level?
SQL> ALTER DATABASE ADD SUPPLEMENTAL LOG DATA;
How to
disable supplemental logging at database level?
SQL> ALTER DATABASE DROP SUPPLEMENTAL LOG DATA;
TABLE LEVEL SUPPLEMENTAL LOGGING:
TABLE LEVEL UNCONDITIONAL SUPPLEMENTAL
LOGGING:
- Primary Key
columns
- All columns
- Selected columns
To
specify an unconditional supplemental log group for PRIMARY
KEY column(s):
SQL
> ALTER TABLE SCOTT. EMP ADD SUPPLEMENTAL LOG DATA (PRIMARY KEY)
COLUMNS;
To
specify an unconditional supplemental log group that includes ALL
TABLE columns:
SQL
> ALTER TABLE SCOTT.EMP ADD SUPPLEMENTAL LOG DATA (ALL)
COLUMNS;
To
specify an unconditional supplemental log group that
includes SELECTED columns:
SQL> ALTER
TABLE SCOTT.EMP ADD SUPPLEMENTAL LOG GROUP t1_g1 (C1,C2) ALWAYS;
TABLE LEVEL CONDITIONAL SUPPLEMENTAL
LOGGING:
- Foreign key
- Unique
- Any Columns
To
specify a conditional supplemental log group that includes all FOREIGN
KEY columns:
SQL> ALTER
TABLE SCOTT.DEPT ADD SUPPLEMENTAL LOG DATA (FOREIGN KEY) COLUMNS;
To
specify a conditional supplemental log group for UNIQUE column(s)
and/or BITMAP index column(s):
SQL
> ALTER TABLE SCOTT.EMP ADD SUPPLEMENTAL LOG DATA
(UNIQUE) COLUMNS;
To
specify a conditional supplemental log group that
includes ANY columns:
SQL>ALTER
TABLE SCOTT.EMP ADD SUPPLEMENTAL LOG GROUP t1_g1 (c1,c3);
To
drop supplemental logging:
SQL >
ALTER TABLE <TABLE NAME >DROP SUPPLEMENTAL LOG DATA (ALL) COLUMNS;
SQL>ALTER
TABLE <TABLE NAME >DROP SUPPLEMENTAL LOG DATA (PRIMARY KEY) COLUMNS;
SQL> ALTER
TABLE <TABLE NAME> DROP SUPPLEMENTAL LOG DATA (UNIQUE) COLUMNS;
SQL> ALTER
TABLE <TABLE NAME> DROP SUPPLEMENTAL LOG DATA (FOREIGN KEY) COLUMNS;
MINIMUM LEVEL OF SUPPLEMENTAL LOGGING
Minimum level of supplemental logging that is required for Oracle Goldengate as per oracle documentation.
ALTER DATABASE ADD SUPPLEMENTAL LOG DATA
By default, Oracle only logs changed columns for update operations. Normally, this means that primary key columns are not logged during an update operation. However, Replicat requires the primary key columns in order to apply the update on the target system. The ADD TRANDATA command in GGSCI is used to cause Oracle to log primary key columns for all updates.
For Golden gate replication minimum level of supplemental logging require is at primary key level to uniquely identify each row for replication purpose.
Golden gate command
ADD TRANDATA scott.DEPT
Actually enable supplemental logging at table level on primary key and running this command in the background
ALTER TABLE "SCOTT"."DEPT" ADD SUPPLEMENTAL LOG GROUP "GGS_DEPT_1668166" ("DEPT_ID") ALWAYS
we have to enable supplemental logging twice as per my understanding because of below reasons.
1. From oracle 10.2 onward minimum level of supplemental logging at database level is required before enabling supplemental logging at table level.
2. Golden gate require minimum primary key supplemental logging which is expensive if enabled at database level when only one schema or few tables are configured for replication.
Minimum level of supplemental logging that is required for Oracle Goldengate as per oracle documentation.
ALTER DATABASE ADD SUPPLEMENTAL LOG DATA
By default, Oracle only logs changed columns for update operations. Normally, this means that primary key columns are not logged during an update operation. However, Replicat requires the primary key columns in order to apply the update on the target system. The ADD TRANDATA command in GGSCI is used to cause Oracle to log primary key columns for all updates.
For Golden gate replication minimum level of supplemental logging require is at primary key level to uniquely identify each row for replication purpose.
Golden gate command
ADD TRANDATA scott.DEPT
Actually enable supplemental logging at table level on primary key and running this command in the background
ALTER TABLE "SCOTT"."DEPT" ADD SUPPLEMENTAL LOG GROUP "GGS_DEPT_1668166" ("DEPT_ID") ALWAYS
we have to enable supplemental logging twice as per my understanding because of below reasons.
1. From oracle 10.2 onward minimum level of supplemental logging at database level is required before enabling supplemental logging at table level.
2. Golden gate require minimum primary key supplemental logging which is expensive if enabled at database level when only one schema or few tables are configured for replication.
Hence basic supplemental logging enable at database level and specific primary
key level on table level via Golden gate.
VIEWS to Check Supplemental logging
DBA_LOG_GROUPS
DBA_LOG_GROUP_COLUMNS