From 1f063c485794ab7c0b167d0185cfb8d27f4bee7b Mon Sep 17 00:00:00 2001 From: richardcevans Date: Thu, 18 Sep 2025 10:13:55 -0500 Subject: [PATCH 1/2] added data redaction demo scripts --- security/data-redaction/README.md | 5 + security/data-redaction/demo.sql | 172 ++++++++++++++++++++++++++++++ 2 files changed, 177 insertions(+) create mode 100644 security/data-redaction/README.md create mode 100644 security/data-redaction/demo.sql diff --git a/security/data-redaction/README.md b/security/data-redaction/README.md new file mode 100644 index 00000000..059bcb94 --- /dev/null +++ b/security/data-redaction/README.md @@ -0,0 +1,5 @@ +# Oracle Data Redaction sample demo script + Data Redaction selectively redacts sensitive data at query runtime, preventing unauthorized exposure, while keeping the underlying data unchanged. Using the sample demo script (demo.sql) examples, we demonstrate key capabilities and recent advancements in Data Redaction introduced with Oracle Database 23ai. . + +To learn more about Data Redaction, visit the Advanced Security product page (https://www.oracle.com/security/database-security/advanced-security/#redact-data) on the Oracle website. For hands-on experience, try our free, interactive Oracle Data Redaction LiveLab (https://apexapps.oracle.com/pls/apex/r/dbpm/livelabs/view-workshop?wid=4061&clear=RR,180&session=1856055320747). + diff --git a/security/data-redaction/demo.sql b/security/data-redaction/demo.sql new file mode 100644 index 00000000..9acbae09 --- /dev/null +++ b/security/data-redaction/demo.sql @@ -0,0 +1,172 @@ +-------------------------------------------------------------------------------- +-- DEMO SCRIPT: Exploring Data Redaction Enhancements in Oracle Database 23ai +-- Requirements: +-- (1) Oracle Database 23ai 23.6+ +-- (2) HR sample schema installed from https://github.com/oracle-samples/db-sample-schemas/releases +-- (3) Privileges to run DBMS_REDACT and alter HR objects (or run as HR) +-------------------------------------------------------------------------------- + +-------------------------------------------------------------------------------- +-- 0. Verify setup +-------------------------------------------------------------------------------- +-- Confirm version +SELECT * FROM v$version; + +-- Confirm HR schema exists +SELECT username FROM all_users WHERE username = 'HR'; + + +-------------------------------------------------------------------------------- +-- 1. Create a basic redaction policy +-- Redact data for all users except HR +-------------------------------------------------------------------------------- +BEGIN + DBMS_REDACT.ADD_POLICY( + object_schema => 'HR', + object_name => 'EMPLOYEES', + policy_name => 'REDACT_DATA', + expression => 'SYS_CONTEXT(''USERENV'',''SESSION_USER'') != ''HR''' + ); +END; +/ +-------------------------------------------------------------------------------- + + +-------------------------------------------------------------------------------- +-- 2. Mathematical and set operators +-- Alter redaction policy to include SALARY column for full redaction +-------------------------------------------------------------------------------- +BEGIN + DBMS_REDACT.ALTER_POLICY( + object_schema => 'HR', + object_name => 'EMPLOYEES', + policy_name => 'REDACT_DATA', + column_name => 'SALARY', + action => DBMS_REDACT.ADD_COLUMN, + function_type => DBMS_REDACT.FULL + ); +END; +/ +-------------------------------------------------------------------------------- + +-- Query employee statistics +SELECT department_id AS dept_id, + COUNT(employee_id) AS emp_count, + AVG(salary) AS avg_salary +FROM hr.employees +GROUP BY department_id +FETCH FIRST 5 ROWS ONLY; +-------------------------------------------------------------------------------- +-- HR user sees real values; non-HR sees 0 for avg_salary +-------------------------------------------------------------------------------- + + +-------------------------------------------------------------------------------- +-- 3. Redaction with GROUP BY and ORDER BY +-------------------------------------------------------------------------------- +SELECT manager_id, + COUNT(DISTINCT employee_id) AS direct_reports, + SUM(salary) AS total_team_salary +FROM hr.employees +GROUP BY manager_id +ORDER BY total_team_salary DESC +FETCH FIRST 5 ROWS ONLY; +-------------------------------------------------------------------------------- +-- HR sees totals; non-HR sees 0 (rows may order differently) +-------------------------------------------------------------------------------- + + +-------------------------------------------------------------------------------- +-- 4. Redacting virtual columns in function-based indexes +-------------------------------------------------------------------------------- + +-- Step 1: Create a function-based index (removes periods and hyphens) +CREATE INDEX hr.phone_number_idx + ON hr.employees( + REPLACE(REPLACE(phone_number, '.', ''), '-', '') + ); + +-- Step 2: Add a virtual column for rounded salary +ALTER TABLE hr.employees ADD ( + rounded_salary AS (ROUND(salary, -3)) +); + +-- Step 3: Apply redaction to PHONE_NUMBER +BEGIN + DBMS_REDACT.ALTER_POLICY( + object_schema => 'HR', + object_name => 'EMPLOYEES', + column_name => 'PHONE_NUMBER', + policy_name => 'REDACT_DATA', + action => DBMS_REDACT.ADD_COLUMN, + function_type => DBMS_REDACT.FULL + ); +END; +/ + +-- Step 4: Update default redaction values +BEGIN + DBMS_REDACT.UPDATE_FULL_REDACTION_VALUES( + number_value => 0, + char_value => 'X' + ); +END; +/ + +-- Step 5: Query redacted virtual columns +SELECT employee_id, phone_number, rounded_salary +FROM hr.employees +WHERE employee_id IN (101, 103, 176, 201); +-------------------------------------------------------------------------------- + + +-------------------------------------------------------------------------------- +-- 5. Redaction in Views with Expressions +-------------------------------------------------------------------------------- + +-- Step 1: Define a view +CREATE OR REPLACE VIEW hr.employee_view AS + SELECT employee_id AS EMP_ID, + ROUND(MONTHS_BETWEEN(SYSDATE, hire_date)/12) AS YEARS_OF_SERVICE, + CONCAT(UPPER(first_name), ' ', UPPER(last_name)) AS FULL_NAME, + EMAIL + FROM hr.employees; + +-- Step 2: Apply redaction to FIRST_NAME +BEGIN + DBMS_REDACT.ALTER_POLICY( + object_schema => 'HR', + object_name => 'EMPLOYEES', + policy_name => 'REDACT_DATA', + column_name => 'FIRST_NAME', + action => DBMS_REDACT.ADD_COLUMN, + function_type => DBMS_REDACT.FULL + ); +END; +/ + +-- Step 3: Apply redaction to EMAIL using regexp +BEGIN + DBMS_REDACT.ALTER_POLICY( + object_schema => 'HR', + object_name => 'EMPLOYEES', + policy_name => 'REDACT_DATA', + column_name => 'EMAIL', + action => DBMS_REDACT.ADD_COLUMN, + function_type => DBMS_REDACT.REGEXP, + regexp_pattern => '^.*$', + regexp_replace_string => 'xxxx@company.com', + regexp_position => 1, + regexp_occurrence => 1, + regexp_match_parameter => 'i' + ); +END; +/ + +-- Step 4: Query the view +SELECT emp_id, years_of_service, full_name, email +FROM hr.employee_view +WHERE emp_id IN (101, 103, 176, 201); +-------------------------------------------------------------------------------- +-- HR sees names/emails; non-HR sees X and xxxx@company.com +-------------------------------------------------------------------------------- From 5778743379050fb68d2c71dc6562d6f127c81dda Mon Sep 17 00:00:00 2001 From: richardcevans Date: Wed, 24 Sep 2025 20:57:48 -0500 Subject: [PATCH 2/2] minor updates updated to check for HR user and updated README with clarifying steps. --- security/data-redaction/README.md | 56 +++++++++++++++++++++++++++++-- security/data-redaction/demo.sql | 23 ++++++++++--- 2 files changed, 72 insertions(+), 7 deletions(-) diff --git a/security/data-redaction/README.md b/security/data-redaction/README.md index 059bcb94..ea5bf169 100644 --- a/security/data-redaction/README.md +++ b/security/data-redaction/README.md @@ -1,5 +1,55 @@ -# Oracle Data Redaction sample demo script - Data Redaction selectively redacts sensitive data at query runtime, preventing unauthorized exposure, while keeping the underlying data unchanged. Using the sample demo script (demo.sql) examples, we demonstrate key capabilities and recent advancements in Data Redaction introduced with Oracle Database 23ai. . +# Demo: Exploring Data Redaction Enhancements in Oracle Database 23ai -To learn more about Data Redaction, visit the Advanced Security product page (https://www.oracle.com/security/database-security/advanced-security/#redact-data) on the Oracle website. For hands-on experience, try our free, interactive Oracle Data Redaction LiveLab (https://apexapps.oracle.com/pls/apex/r/dbpm/livelabs/view-workshop?wid=4061&clear=RR,180&session=1856055320747). +This demo script showcases new **Oracle Data Redaction** capabilities in Oracle Database 23ai (23.6+). +It walks through creating and altering redaction policies, applying them to tables, virtual columns, indexes, and views, and observing how results differ for **HR** versus non-HR users. + +## Requirements + +- **Oracle Database 23ai 23.6+** +- **HR sample schema** installed from [Oracle Sample Schemas](https://github.com/oracle-samples/db-sample-schemas/releases) +- Privileges to run `DBMS_REDACT` and alter objects in the HR schema (recommended: run as HR) + + +## Script Sections + +### 0. Verify Setup +- Confirms **HR schema** exists +- Confirms **Database version ≥ 23** +- Script exits if either requirement is not met + +### 1. Basic Redaction Policy +- Creates a policy on `HR.EMPLOYEES` +- Redacts data for all users except HR + +### 2. Mathematical and Set Operators +- Adds redaction to the `SALARY` column +- Demonstrates impact on `GROUP BY` queries (e.g., average salary) + +### 3. Redaction with GROUP BY and ORDER BY +- Queries team statistics by manager +- Shows difference in totals/order for HR vs non-HR users + +### 4. Redacting Virtual Columns & Function-Based Indexes +- Creates a function-based index on `PHONE_NUMBER` +- Adds a virtual column (`ROUNDED_SALARY`) +- Applies redaction to `PHONE_NUMBER` +- Updates default redaction values (e.g., numbers -> 0, chars -> X) +- Queries redacted results + +### 5. Redaction in Views with Expressions +- Creates a view `HR.EMPLOYEE_VIEW` with calculated columns +- Redacts `FIRST_NAME` (full) +- Redacts `EMAIL` using **regular expression replacement** +- Queries the view to illustrate differences for HR vs non-HR users + +--- + +## How to Run +1. Connect as a user with privileges (e.g., `HR`) in **SQL*Plus** or **SQL Developer** +2. Execute the script + + +## To learn more about Oracle Data Redaction: +- Visit the Advanced Security product page (https://www.oracle.com/security/database-security/advanced-security/#redact-data) on the Oracle website. +- For hands-on experience, try our free, interactive Oracle Data Redaction LiveLab (https://apexapps.oracle.com/pls/apex/r/dbpm/livelabs/view-workshop?wid=4061&clear=RR,180&session=1856055320747). diff --git a/security/data-redaction/demo.sql b/security/data-redaction/demo.sql index 9acbae09..f47ef840 100644 --- a/security/data-redaction/demo.sql +++ b/security/data-redaction/demo.sql @@ -9,11 +9,26 @@ -------------------------------------------------------------------------------- -- 0. Verify setup -------------------------------------------------------------------------------- --- Confirm version -SELECT * FROM v$version; +SET SERVEROUTPUT ON; --- Confirm HR schema exists -SELECT username FROM all_users WHERE username = 'HR'; +DECLARE + v_count NUMBER; + v_version NUMBER; +BEGIN + -- Check HR schema + SELECT COUNT(*) INTO v_count FROM all_users WHERE username = 'HR'; + IF v_count = 0 THEN + RAISE_APPLICATION_ERROR(-20001, 'ERROR: HR schema not found. Exiting.'); + END IF; + + -- Check DB version >= 23 + SELECT TO_NUMBER(REGEXP_SUBSTR(version, '^[0-9]+')) INTO v_version FROM v$instance; + IF v_version < 23 THEN + RAISE_APPLICATION_ERROR(-20002, 'ERROR: Requires DB version 23 or higher. Exiting.'); + END IF; +END; +/ +-------------------------------------------------------------------------------- --------------------------------------------------------------------------------