How Do I Grant the Log Archiving, Query, and Parsing Permissions of an Oracle Data Source?
Symptom
The default permissions of the Oracle data source are insufficient for executing real-time processing migration jobs.
Possible Cause
- The log archiving function must be enabled for the Oracle database. It is recommended that archived logs be retained for at least three days.
- The permissions for querying Oracle tables or parsing logs are missing.
Solution
- Enable log archiving.
- Log in to the Oracle database as user sysdba.
- Run the SQL command ARCHIVE LOG LIST to query the archiving status of the current database. The following information indicates that log archiving is disabled:
Database log mode No Archive Mode #Log archiving is disabled. Automatic archival Disabled Archive destination USE_DB_RECOVERY_FILE_DEST Oldest online log sequence 1 Current log sequence 2
- Run the SQL command SHUTDOWN IMMEDIATE to shut down the database.
- Run the SQL command STARTUP MOUNT to start the database in MOUNT state.
- Run the SQL command ALTER DATABASE ARCHIVELOG to enable archiving mode.
- Run the SQL command ARCHIVE LOG LIST to query the archiving status. The following information indicates that log archiving is enabled:
Databaselogmode Archive Mode #Log archiving is enabled. Automatic archival Enabled Archive destination USE_DB_RECOVERY_FILE_DEST Oldest online log sequence 1 Next log sequence to archive 2 Currentlogsequence 2
- Run the SQL command ALTER DATABASE OPEN to start the database.
- Enable supplementary logs for the Oracle database and tables to be migrated.
- Run the following SQL statement to enable supplemental logs for the database:
ALTER DATABASE ADD SUPPLEMENTAL LOG DATA;
- Enable supplemental logs for the tables to be synchronized in real time.
ALTER TABLE "schema_name"."table_name" ADD SUPPLEMENTAL LOG DATA (ALL) COLUMNS;
After the setting is successful, run the following SQL statement. If ALL_COLUMN_LOGGING is returned, supplemental logs are enabled for the tables:
SELECT 'KEY', LOG_GROUP_TYPE FROM ALL_LOG_GROUPS WHERE OWNER = 'schema_name' AND TABLE_NAME = 'table_name'; "KEY" LOG_GROUP_TYPE KEY ALL_COLUMN_LOGGING
- Run the following SQL statement to enable supplemental logs for the database:
- Grant required permissions to the Oracle user.
- Reference commands for granting permissions to Oracle 19 users:
sqlplus sys/password@//localhost:1521/ORCLCDB as sysdba CREATE USER mgrationuser IDENTIFIED BY mgrationuserPWD DEFAULT TABLESPACE logminer_tbs QUOTA UNLIMITED ON logminer_tbs CONTAINER=ALL; GRANT CREATE SESSION TO mgrationuser CONTAINER=ALL; GRANT SET CONTAINER TO mgrationuser CONTAINER=ALL; GRANT SELECT ON V_$DATABASE to mgrationuser CONTAINER=ALL; GRANT FLASHBACK ANY TABLE TO mrationuser CONTAINER=ALL; GRANT SELECT ANY TABLE TO mgrationuser CONTAINER=ALL; GRANT SELECT_CATALOG_ROLE TO mgrationuser CONTAINER=ALL; GRANT EXECUTE_CATALOG_ROLE TO mgrationuser CONTAINER=ALL; GRANT SELECT ANY TRANSACTION TO mgrationuser CONTAINER=ALL; GRANT LOGMINING TO mgrationuser CONTAINER=ALL; GRANT CREATE TABLE TO mgrationuser CONTAINER=ALL; -- Don't need to execute this statement, If you set 'scan.incremental.snapshot.enabled=true' (default). GRANT LOCK ANY TABLE TO mgrationuser CONTAINER=ALL; GRANT CREATE SEQUENCE TO mgrationuser CONTAINER=ALL; GRANT EXECUTE ON DBMS_LOGMNR TO mgrationuser CONTAINER=ALL; GRANT EXECUTE ON DBMS_LOGMNR_D TO mgrationuser CONTAINER=ALL; GRANT SELECT ON V_$LOG TO mgrationuser CONTAINER=ALL; GRANT SELECT ON V_$LOG_HISTORY TO mgrationuser CONTAINER=ALL; GRANT SELECT ON V_$LOGMNR_LOGS TO mgrationuser CONTAINER=ALL; GRANT SELECT ON V_$LOGMNR_CONTENTS TO mgrationuser CONTAINER=ALL; GRANT SELECT ON V_$LOGMNR_PARAMETERS TO mgrationuser CONTAINER=ALL; GRANT SELECT ON V_$LOGFILE TO mgrationuser CONTAINER=ALL; GRANT SELECT ON V_$ARCHIVED_LOG TO mgrationuser CONTAINER=ALL; GRANT SELECT ON V_$ARCHIVE_DEST_STATUS TO mgrationuser CONTAINER=ALL; exit;
- Reference commands for granting permissions to Oracle 11g users:
sqlplus sys/password@host:port/SID AS SYSDBA; CREATE USER mgrationuser IDENTIFIED BY mgrationuserPDW DEFAULT TABLESPACE LOGMINER_TBS QUOTA UNLIMITED ON LOGMINER_TBS; GRANT CREATE SESSION TO mgrationuser; GRANT SELECT ON V_$DATABASE to mgrationuser; GRANT FLASHBACK ANY TABLE TO mgrationuser; GRANT SELECT ANY TABLE TO mgrationuser; GRANT SELECT_CATALOG_ROLE TO mgrationuser; GRANT EXECUTE_CATALOG_ROLE TO mgrationuser; GRANT SELECT ANY TRANSACTION TO mgrationuser; GRANT CREATE TABLE TO mgrationuser; GRANT LOCK ANY TABLE TO mgrationuser; GRANT ALTER ANY TABLE TO mgrationuser; GRANT CREATE SEQUENCE TO mgrationuser; GRANT EXECUTE ON DBMS_LOGMNR TO mgrationuser; GRANT EXECUTE ON DBMS_LOGMNR_D TO mgrationuser; GRANT SELECT ON V_$LOG TO mgrationuser; GRANT SELECT ON V_$LOG_HISTORY TO mgrationuser; GRANT SELECT ON V_$LOGMNR_LOGS TO mgrationuser; GRANT SELECT ON V_$LOGMNR_CONTENTS TO mgrationuser; GRANT SELECT ON V_$LOGMNR_PARAMETERS TO mgrationuser; GRANT SELECT ON V_$LOGFILE TO mgrationuser; GRANT SELECT ON V_$ARCHIVED_LOG TO mgrationuser; GRANT SELECT ON V_$ARCHIVE_DEST_STATUS TO mgrationuser; exit
- Reference commands for granting permissions to Oracle 19 users:
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot