Updated oracle to use DBA_ tables (#17274)

Co-authored-by: Ayush Shah <ayush@getcollate.io>
This commit is contained in:
IceS2 2024-08-10 13:28:21 +02:00 committed by GitHub
parent d3cbd5e428
commit e5a7cff5a5
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
9 changed files with 243 additions and 38 deletions

View File

@ -54,6 +54,7 @@ from metadata.ingestion.source.database.oracle.queries import (
)
from metadata.ingestion.source.database.oracle.utils import (
_get_col_type,
_get_constraint_data,
get_columns,
get_mview_definition,
get_mview_names,
@ -61,6 +62,8 @@ from metadata.ingestion.source.database.oracle.utils import (
get_table_comment,
get_table_names,
get_view_definition,
get_view_names,
get_view_names_dialect,
)
from metadata.ingestion.source.database.stored_procedures_mixin import (
QueryByProcedure,
@ -97,10 +100,14 @@ OracleDialect.get_table_names = get_table_names
Inspector.get_mview_names = get_mview_names
Inspector.get_mview_definition = get_mview_definition
OracleDialect.get_mview_names = get_mview_names_dialect
Inspector.get_view_names = get_view_names
OracleDialect.get_view_names = get_view_names_dialect
Inspector.get_all_table_ddls = get_all_table_ddls
Inspector.get_table_ddl = get_table_ddl
OracleDialect._get_constraint_data = _get_constraint_data
class OracleSource(StoredProcedureMixin, CommonDbSourceService):
"""

View File

@ -20,7 +20,7 @@ SELECT
comments table_comment,
LOWER(table_name) "table_name",
LOWER(owner) "schema"
FROM ALL_TAB_COMMENTS
FROM DBA_TAB_COMMENTS
where comments is not null and owner not in ('SYSTEM', 'SYS')
"""
)
@ -32,33 +32,39 @@ SELECT
LOWER(view_name) AS "view_name",
LOWER(owner) AS "schema",
DBMS_METADATA.GET_DDL('VIEW', view_name, owner) AS view_def
FROM ALL_VIEWS
FROM DBA_VIEWS
WHERE owner NOT IN ('SYSTEM', 'SYS')
UNION ALL
SELECT
LOWER(mview_name) AS "view_name",
LOWER(owner) AS "schema",
DBMS_METADATA.GET_DDL('MATERIALIZED_VIEW', mview_name, owner) AS view_def
FROM ALL_MVIEWS
FROM DBA_MVIEWS
WHERE owner NOT IN ('SYSTEM', 'SYS')
"""
)
GET_VIEW_NAMES = textwrap.dedent(
"""
SELECT view_name FROM DBA_VIEWS WHERE owner = :owner
"""
)
GET_MATERIALIZED_VIEW_NAMES = textwrap.dedent(
"""
SELECT mview_name FROM ALL_MVIEWS WHERE owner = :owner
SELECT mview_name FROM DBA_MVIEWS WHERE owner = :owner
"""
)
ORACLE_GET_TABLE_NAMES = textwrap.dedent(
"""
SELECT table_name FROM ALL_TABLES WHERE
SELECT table_name FROM DBA_TABLES WHERE
{tablespace}
OWNER = :owner
AND IOT_NAME IS NULL
AND DURATION IS NULL
AND TABLE_NAME NOT IN
(SELECT mview_name FROM ALL_MVIEWS WHERE owner = :owner)
(SELECT mview_name FROM DBA_MVIEWS WHERE owner = :owner)
"""
)
@ -67,7 +73,7 @@ ORACLE_IDENTITY_TYPE = textwrap.dedent(
col.default_on_null,
(
SELECT id.generation_type || ',' || id.IDENTITY_OPTIONS
FROM ALL_TAB_IDENTITY_COLS{dblink} id
FROM DBA_TAB_IDENTITY_COLS{dblink} id
WHERE col.table_name = id.table_name
AND col.column_name = id.column_name
AND col.owner = id.owner
@ -83,12 +89,12 @@ SELECT
LINE,
TEXT
FROM
ALL_SOURCE
DBA_SOURCE
WHERE
type = 'PROCEDURE' and owner = '{schema}'
"""
)
CHECK_ACCESS_TO_ALL = "SELECT table_name FROM ALL_TABLES where ROWNUM < 2"
CHECK_ACCESS_TO_ALL = "SELECT table_name FROM DBA_TABLES where ROWNUM < 2"
ORACLE_GET_STORED_PROCEDURE_QUERIES = textwrap.dedent(
"""
WITH SP_HISTORY AS (SELECT
@ -98,7 +104,7 @@ WITH SP_HISTORY AS (SELECT
PARSING_SCHEMA_NAME as user_name
FROM gv$sql
WHERE UPPER(sql_text) LIKE '%%CALL%%' or UPPER(sql_text) LIKE '%%BEGIN%%'
AND TO_TIMESTAMP(FIRST_LOAD_TIME, 'YYYY-MM-DD HH24:MI:SS') >= TO_TIMESTAMP('{start_date}', 'YYYY-MM-DD HH24:MI:SS')
AND TO_TIMESTAMP(FIRST_LOAD_TIME, 'YYYY-MM-DD HH24:MI:SS') >= TO_TIMESTAMP_TZ('{start_date}', 'YYYY-MM-DD HH24:MI:SS+TZH:TZM')
),
Q_HISTORY AS (SELECT
sql_text AS query_text,
@ -118,7 +124,7 @@ WITH SP_HISTORY AS (SELECT
AND SQL_FULLTEXT NOT LIKE '/* {{"app": "OpenMetadata", %%}} */%%'
AND SQL_FULLTEXT NOT LIKE '/* {{"app": "dbt", %%}} */%%'
AND TO_TIMESTAMP(FIRST_LOAD_TIME, 'YYYY-MM-DD HH24:MI:SS')
>= TO_TIMESTAMP('{start_date}', 'YYYY-MM-DD HH24:MI:SS')
>= TO_TIMESTAMP_TZ('{start_date}', 'YYYY-MM-DD HH24:MI:SS+TZH:TZM')
)
SELECT
Q.QUERY_TYPE AS QUERY_TYPE,
@ -153,8 +159,8 @@ ORACLE_GET_COLUMNS = textwrap.dedent(
com.comments,
col.virtual_column,
{identity_cols}
FROM ALL_TAB_COLS{dblink} col
LEFT JOIN ALL_COL_COMMENTS{dblink} com
FROM DBA_TAB_COLS{dblink} col
LEFT JOIN DBA_COL_COMMENTS{dblink} com
ON col.table_name = com.table_name
AND col.column_name = com.column_name
AND col.owner = com.owner
@ -163,6 +169,34 @@ ORACLE_GET_COLUMNS = textwrap.dedent(
"""
)
ORACLE_ALL_CONSTRAINTS = textwrap.dedent(
"""
SELECT
ac.constraint_name,
ac.constraint_type,
loc.column_name AS local_column,
rem.table_name AS remote_table,
rem.column_name AS remote_column,
rem.owner AS remote_owner,
loc.position as loc_pos,
rem.position as rem_pos,
ac.search_condition,
ac.delete_rule
FROM DBA_CONSTRAINTS{dblink} ac,
DBA_CONS_COLUMNS{dblink} loc,
DBA_CONS_COLUMNS{dblink} rem
WHERE ac.table_name = CAST(:table_name AS VARCHAR2(128))
AND ac.constraint_type IN ('R','P', 'U', 'C')
AND ac.owner = CAST(:owner AS VARCHAR2(128))
AND ac.owner = loc.owner
AND ac.constraint_name = loc.constraint_name
AND ac.r_owner = rem.owner(+)
AND ac.r_constraint_name = rem.constraint_name(+)
AND (rem.position IS NULL or loc.position=rem.position)
ORDER BY ac.constraint_name, loc.position
"""
)
ORACLE_QUERY_HISTORY_STATEMENT = textwrap.dedent(
"""
SELECT

View File

@ -21,6 +21,8 @@ from sqlalchemy.sql import sqltypes
from metadata.ingestion.source.database.oracle.queries import (
GET_MATERIALIZED_VIEW_NAMES,
GET_VIEW_NAMES,
ORACLE_ALL_CONSTRAINTS,
ORACLE_ALL_TABLE_COMMENTS,
ORACLE_ALL_VIEW_DEFINITIONS,
ORACLE_GET_COLUMNS,
@ -222,6 +224,26 @@ def get_table_names(self, connection, schema=None, **kw):
return [row[0] for row in cursor]
def get_view_names(self, schema=None):
"""Return all materialized view names in `schema`.
:param schema: Optional, retrieve names from a non-default schema.
For special quoting, use :class:`.quoted_name`.
"""
with self._operation_context() as conn:
return self.dialect.get_view_names(conn, schema, info_cache=self.info_cache)
@reflection.cache
def get_view_names_dialect(self, connection, schema=None, **kw):
schema = self.denormalize_name(schema or self.default_schema_name)
sql_query = sql.text(GET_VIEW_NAMES)
cursor = connection.execute(sql_query, {"owner": self.denormalize_name(schema)})
return [self.normalize_name(row[0]) for row in cursor]
def get_mview_names(self, schema=None):
"""Return all materialized view names in `schema`.
@ -254,3 +276,14 @@ def get_mview_definition(self, mview_name, schema=None):
return self.dialect.get_view_definition(
conn, mview_name, schema, info_cache=self.info_cache
)
@reflection.cache
def _get_constraint_data(self, connection, table_name, schema=None, dblink="", **kw):
params = {"table_name": table_name, "owner": schema}
text = ORACLE_ALL_CONSTRAINTS.format(dblink=dblink)
rp = connection.execute(sql.text(text), params)
constraint_data = rp.fetchall()
return constraint_data

View File

@ -194,7 +194,7 @@ class OracleTableMetricComputer(BaseTableMetricComputer):
Column("object_name").label("table_name"),
Column("created"),
],
self._build_table("all_objects", None),
self._build_table("DBA_OBJECTS", None),
[
func.lower(Column("owner")) == self.schema_name.lower(),
func.lower(Column("object_name")) == self.table_name.lower(),
@ -209,7 +209,7 @@ class OracleTableMetricComputer(BaseTableMetricComputer):
Column("table_name"),
Column("NUM_ROWS"),
],
self._build_table("all_tables", None),
self._build_table("DBA_TABLES", None),
[
func.lower(Column("owner")) == self.schema_name.lower(),
func.lower(Column("table_name")) == self.table_name.lower(),

View File

@ -40,20 +40,54 @@ CREATE ROLE new_role;
-- GRANT ROLE TO USER
GRANT new_role TO user_name;
-- GRANT CREATE SESSION PRIVILEGE TO USER
-- Grant CREATE SESSION Privilege.
-- This allows the role to connect.
GRANT CREATE SESSION TO new_role;
-- GRANT SELECT CATALOG ROLE PRIVILEGE TO FETCH METADATA TO ROLE / USER
-- Grant SELECT_CATALOG_ROLE Privilege.
-- This allows the role ReadOnly Access to Data Dictionaries
GRANT SELECT_CATALOG_ROLE TO new_role;
```
With just these permissions, your user should be able to ingest the schemas, but not the tables inside them. To get
the tables, you should grant `SELECT` permissions to the tables you are interested in. E.g.,
If you don't want to create a role, and directly give permissions to the user, you can take a look at an example given below.
```sql
SELECT ON ADMIN.EXAMPLE_TABLE TO new_role;
-- Create a New User
CREATE USER my_user IDENTIFIED by my_password;
-- Grant CREATE SESSION Privilege.
-- This allows the user to connect.
GRANT CREATE SESSION TO my_user;
-- Grant SELECT_CATALOG_ROLE Privilege.
-- This allows the user ReadOnly Access to Data Dictionaries
GRANT SELECT_CATALOG_ROLE to my_user;
```
With just these permissions, your user should be able to ingest the metadata of entities for which the user has access to. E.g.,
```sql
-- If you are using a role and do not want to specify a specific table, but any
GRANT SELECT ANY TABLE TO new_role;
-- If you are not using a role, but directly giving permission to the user and do not want to specify a specific table, but any
GRANT SELECT ANY TABLE TO my_user;
-- if you are using role
GRANT SELECT ON ADMIN.EXAMPLE_TABLE TO new_role;
-- if you are not using role, but directly giving permission to the user
GRANT SELECT ON ADMIN.EXAMPLE_TABLE TO my_user;
-- if you are using role
GRANT SELECT ON {schema}.{table} TO new_role;
-- if you are not using role, but directly giving permission to the user
GRANT SELECT ON {schema}.{table} TO my_user;
```
You can find further information [here](https://docs.oracle.com/javadb/10.8.3.0/ref/rrefsqljgrant.html). Note that
there is no routine out of the box in Oracle to grant SELECT to a full schema.

View File

@ -26,7 +26,7 @@ Configure and schedule Oracle metadata and profiler workflows from the OpenMetad
## Requirements
**Note**: To retrieve metadata from an Oracle database, the python-oracledb library can be utilized, which provides support for versions 12c, 18c, 19c, and 21c.
**Note**: To retrieve metadata from an Oracle database, we use the `python-oracledb` library, which provides support for versions 12c, 18c, 19c, and 21c.
To ingest metadata from oracle user must have `CREATE SESSION` privilege for the user.
@ -40,18 +40,51 @@ CREATE ROLE new_role;
-- GRANT ROLE TO USER
GRANT new_role TO user_name;
-- GRANT CREATE SESSION PRIVILEGE TO USER
-- Grant CREATE SESSION Privilege.
-- This allows the role to connect.
GRANT CREATE SESSION TO new_role;
-- GRANT SELECT CATALOG ROLE PRIVILEGE TO FETCH METADATA TO ROLE / USER
-- Grant SELECT_CATALOG_ROLE Privilege.
-- This allows the role ReadOnly Access to Data Dictionaries
GRANT SELECT_CATALOG_ROLE TO new_role;
```
With just these permissions, your user should be able to ingest the schemas, but not the tables inside them. To get
the tables, you should grant `SELECT` permissions to the tables you are interested in. E.g.,
If you don't want to create a role, and directly give permissions to the user, you can take a look at an example given below.
```sql
SELECT ON ADMIN.EXAMPLE_TABLE TO new_role;
-- Create a New User
CREATE USER my_user IDENTIFIED by my_password;
-- Grant CREATE SESSION Privilege.
-- This allows the user to connect.
GRANT CREATE SESSION TO my_user;
-- Grant SELECT_CATALOG_ROLE Privilege.
-- This allows the user ReadOnly Access to Data Dictionaries
GRANT SELECT_CATALOG_ROLE to my_user;
```
With just these permissions, your user should be able to ingest the metadata of entities for which the user has access to. E.g.,
```sql
-- If you are using a role and do not want to specify a specific table, but any
GRANT SELECT ANY TABLE TO new_role;
-- If you are not using a role, but directly giving permission to the user and do not want to specify a specific table, but any
GRANT SELECT ANY TABLE TO my_user;
-- if you are using role
GRANT SELECT ON ADMIN.EXAMPLE_TABLE TO new_role;
-- if you are not using role, but directly giving permission to the user
GRANT SELECT ON ADMIN.EXAMPLE_TABLE TO my_user;
-- if you are using role
GRANT SELECT ON {schema}.{table} TO new_role;
-- if you are not using role, but directly giving permission to the user
GRANT SELECT ON {schema}.{table} TO my_user;
```
You can find further information [here](https://docs.oracle.com/javadb/10.8.3.0/ref/rrefsqljgrant.html). Note that

View File

@ -40,18 +40,50 @@ CREATE ROLE new_role;
-- GRANT ROLE TO USER
GRANT new_role TO user_name;
-- GRANT CREATE SESSION PRIVILEGE TO USER
-- Grant CREATE SESSION Privilege.
-- This allows the role to connect.
GRANT CREATE SESSION TO new_role;
-- GRANT SELECT CATALOG ROLE PRIVILEGE TO FETCH METADATA TO ROLE / USER
-- Grant SELECT_CATALOG_ROLE Privilege.
-- This allows the role ReadOnly Access to Data Dictionaries
GRANT SELECT_CATALOG_ROLE TO new_role;
```
With just these permissions, your user should be able to ingest the schemas, but not the tables inside them. To get
the tables, you should grant `SELECT` permissions to the tables you are interested in. E.g.,
If you don't want to create a role, and directly give permissions to the user, you can take a look at an example given below.
```sql
SELECT ON ADMIN.EXAMPLE_TABLE TO new_role;
-- Create a New User
CREATE USER my_user IDENTIFIED by my_password;
-- Grant CREATE SESSION Privilege.
-- This allows the user to connect.
GRANT CREATE SESSION TO my_user;
-- Grant SELECT_CATALOG_ROLE Privilege.
-- This allows the user ReadOnly Access to Data Dictionaries
GRANT SELECT_CATALOG_ROLE to my_user;
```
**Note**: With just these permissions, your user should be able to ingest the metadata, but not the `Profiler & Data Quality`, you should grant `SELECT` permissions to the tables you are interested in for the `Profiler & Data Quality` features to work.
```sql
-- If you are using a role and do not want to specify a specific table, but any
GRANT SELECT ANY TABLE TO new_role;
-- If you are not using a role, but directly giving permission to the user and do not want to specify a specific table, but any
GRANT SELECT ANY TABLE TO my_user;
-- if you are using role
GRANT SELECT ON ADMIN.EXAMPLE_TABLE TO new_role;
-- if you are not using role, but directly giving permission to the user
GRANT SELECT ON ADMIN.EXAMPLE_TABLE TO my_user;
-- if you are using role
GRANT SELECT ON {schema}.{table} TO new_role;
-- if you are not using role, but directly giving permission to the user
GRANT SELECT ON {schema}.{table} TO my_user;
```
You can find further information [here](https://docs.oracle.com/javadb/10.8.3.0/ref/rrefsqljgrant.html). Note that

View File

@ -26,7 +26,7 @@ Configure and schedule Oracle metadata and profiler workflows from the OpenMetad
## Requirements
**Note**: To retrieve metadata from an Oracle database, the python-oracledb library can be utilized, which provides support for versions 12c, 18c, 19c, and 21c.
**Note**: To retrieve metadata from an Oracle database, we use the `python-oracledb` library, which provides support for versions 12c, 18c, 19c, and 21c.
To ingest metadata from oracle user must have `CREATE SESSION` privilege for the user.
@ -40,18 +40,50 @@ CREATE ROLE new_role;
-- GRANT ROLE TO USER
GRANT new_role TO user_name;
-- GRANT CREATE SESSION PRIVILEGE TO USER
-- Grant CREATE SESSION Privilege.
-- This allows the role to connect.
GRANT CREATE SESSION TO new_role;
-- GRANT SELECT CATALOG ROLE PRIVILEGE TO FETCH METADATA TO ROLE / USER
-- Grant SELECT_CATALOG_ROLE Privilege.
-- This allows the role ReadOnly Access to Data Dictionaries
GRANT SELECT_CATALOG_ROLE TO new_role;
```
With just these permissions, your user should be able to ingest the schemas, but not the tables inside them. To get
the tables, you should grant `SELECT` permissions to the tables you are interested in. E.g.,
If you don't want to create a role, and directly give permissions to the user, you can take a look at an example given below.
```sql
SELECT ON ADMIN.EXAMPLE_TABLE TO new_role;
-- Create a New User
CREATE USER my_user IDENTIFIED by my_password;
-- Grant CREATE SESSION Privilege.
-- This allows the user to connect.
GRANT CREATE SESSION TO my_user;
-- Grant SELECT_CATALOG_ROLE Privilege.
-- This allows the user ReadOnly Access to Data Dictionaries
GRANT SELECT_CATALOG_ROLE to my_user;
```
**Note**: With just these permissions, your user should be able to ingest the metadata, but not the `Profiler & Data Quality`, you should grant `SELECT` permissions to the tables you are interested in for the `Profiler & Data Quality` features to work.
```sql
-- If you are using a role and do not want to specify a specific table, but any
GRANT SELECT ANY TABLE TO new_role;
-- If you are not using a role, but directly giving permission to the user and do not want to specify a specific table, but any
GRANT SELECT ANY TABLE TO my_user;
-- if you are using role
GRANT SELECT ON ADMIN.EXAMPLE_TABLE TO new_role;
-- if you are not using role, but directly giving permission to the user
GRANT SELECT ON ADMIN.EXAMPLE_TABLE TO my_user;
-- if you are using role
GRANT SELECT ON {schema}.{table} TO new_role;
-- if you are not using role, but directly giving permission to the user
GRANT SELECT ON {schema}.{table} TO my_user;
```
You can find further information [here](https://docs.oracle.com/javadb/10.8.3.0/ref/rrefsqljgrant.html). Note that

View File

@ -6,7 +6,7 @@
{
"name": "CheckAccess",
"description": "Validate that we can properly reach the database and authenticate with the given credentials.",
"errorMessage": "Failed to connect to oracle, please validate the credentials",
"errorMessage": "Failed to connect to oracle, please validate if the user has relevant permissions, if not, please provide the necessary permissions. For more details, please refer https://docs.open-metadata.org/connectors/database/oracle.",
"shortCircuit": true,
"mandatory": true
},