Skip to content

Commit ae815a3

Browse files
added data redaction demo scripts (#454)
* added data redaction demo scripts * minor updates updated to check for HR user and updated README with clarifying steps.
1 parent d0b3e4f commit ae815a3

File tree

2 files changed

+242
-0
lines changed

2 files changed

+242
-0
lines changed

security/data-redaction/README.md

Lines changed: 55 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,55 @@
1+
# Demo: Exploring Data Redaction Enhancements in Oracle Database 23ai
2+
3+
This demo script showcases new **Oracle Data Redaction** capabilities in Oracle Database 23ai (23.6+).
4+
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.
5+
6+
## Requirements
7+
8+
- **Oracle Database 23ai 23.6+**
9+
- **HR sample schema** installed from [Oracle Sample Schemas](https://github.com/oracle-samples/db-sample-schemas/releases)
10+
- Privileges to run `DBMS_REDACT` and alter objects in the HR schema (recommended: run as HR)
11+
12+
13+
## Script Sections
14+
15+
### 0. Verify Setup
16+
- Confirms **HR schema** exists
17+
- Confirms **Database version ≥ 23**
18+
- Script exits if either requirement is not met
19+
20+
### 1. Basic Redaction Policy
21+
- Creates a policy on `HR.EMPLOYEES`
22+
- Redacts data for all users except HR
23+
24+
### 2. Mathematical and Set Operators
25+
- Adds redaction to the `SALARY` column
26+
- Demonstrates impact on `GROUP BY` queries (e.g., average salary)
27+
28+
### 3. Redaction with GROUP BY and ORDER BY
29+
- Queries team statistics by manager
30+
- Shows difference in totals/order for HR vs non-HR users
31+
32+
### 4. Redacting Virtual Columns & Function-Based Indexes
33+
- Creates a function-based index on `PHONE_NUMBER`
34+
- Adds a virtual column (`ROUNDED_SALARY`)
35+
- Applies redaction to `PHONE_NUMBER`
36+
- Updates default redaction values (e.g., numbers -> 0, chars -> X)
37+
- Queries redacted results
38+
39+
### 5. Redaction in Views with Expressions
40+
- Creates a view `HR.EMPLOYEE_VIEW` with calculated columns
41+
- Redacts `FIRST_NAME` (full)
42+
- Redacts `EMAIL` using **regular expression replacement**
43+
- Queries the view to illustrate differences for HR vs non-HR users
44+
45+
---
46+
47+
## How to Run
48+
1. Connect as a user with privileges (e.g., `HR`) in **SQL*Plus** or **SQL Developer**
49+
2. Execute the script
50+
51+
52+
## To learn more about Oracle Data Redaction:
53+
- Visit the Advanced Security product page (https://www.oracle.com/security/database-security/advanced-security/#redact-data) on the Oracle website.
54+
- 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).
55+

security/data-redaction/demo.sql

Lines changed: 187 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,187 @@
1+
--------------------------------------------------------------------------------
2+
-- DEMO SCRIPT: Exploring Data Redaction Enhancements in Oracle Database 23ai
3+
-- Requirements:
4+
-- (1) Oracle Database 23ai 23.6+
5+
-- (2) HR sample schema installed from https://github.com/oracle-samples/db-sample-schemas/releases
6+
-- (3) Privileges to run DBMS_REDACT and alter HR objects (or run as HR)
7+
--------------------------------------------------------------------------------
8+
9+
--------------------------------------------------------------------------------
10+
-- 0. Verify setup
11+
--------------------------------------------------------------------------------
12+
SET SERVEROUTPUT ON;
13+
14+
DECLARE
15+
v_count NUMBER;
16+
v_version NUMBER;
17+
BEGIN
18+
-- Check HR schema
19+
SELECT COUNT(*) INTO v_count FROM all_users WHERE username = 'HR';
20+
IF v_count = 0 THEN
21+
RAISE_APPLICATION_ERROR(-20001, 'ERROR: HR schema not found. Exiting.');
22+
END IF;
23+
24+
-- Check DB version >= 23
25+
SELECT TO_NUMBER(REGEXP_SUBSTR(version, '^[0-9]+')) INTO v_version FROM v$instance;
26+
IF v_version < 23 THEN
27+
RAISE_APPLICATION_ERROR(-20002, 'ERROR: Requires DB version 23 or higher. Exiting.');
28+
END IF;
29+
END;
30+
/
31+
--------------------------------------------------------------------------------
32+
33+
34+
--------------------------------------------------------------------------------
35+
-- 1. Create a basic redaction policy
36+
-- Redact data for all users except HR
37+
--------------------------------------------------------------------------------
38+
BEGIN
39+
DBMS_REDACT.ADD_POLICY(
40+
object_schema => 'HR',
41+
object_name => 'EMPLOYEES',
42+
policy_name => 'REDACT_DATA',
43+
expression => 'SYS_CONTEXT(''USERENV'',''SESSION_USER'') != ''HR'''
44+
);
45+
END;
46+
/
47+
--------------------------------------------------------------------------------
48+
49+
50+
--------------------------------------------------------------------------------
51+
-- 2. Mathematical and set operators
52+
-- Alter redaction policy to include SALARY column for full redaction
53+
--------------------------------------------------------------------------------
54+
BEGIN
55+
DBMS_REDACT.ALTER_POLICY(
56+
object_schema => 'HR',
57+
object_name => 'EMPLOYEES',
58+
policy_name => 'REDACT_DATA',
59+
column_name => 'SALARY',
60+
action => DBMS_REDACT.ADD_COLUMN,
61+
function_type => DBMS_REDACT.FULL
62+
);
63+
END;
64+
/
65+
--------------------------------------------------------------------------------
66+
67+
-- Query employee statistics
68+
SELECT department_id AS dept_id,
69+
COUNT(employee_id) AS emp_count,
70+
AVG(salary) AS avg_salary
71+
FROM hr.employees
72+
GROUP BY department_id
73+
FETCH FIRST 5 ROWS ONLY;
74+
--------------------------------------------------------------------------------
75+
-- HR user sees real values; non-HR sees 0 for avg_salary
76+
--------------------------------------------------------------------------------
77+
78+
79+
--------------------------------------------------------------------------------
80+
-- 3. Redaction with GROUP BY and ORDER BY
81+
--------------------------------------------------------------------------------
82+
SELECT manager_id,
83+
COUNT(DISTINCT employee_id) AS direct_reports,
84+
SUM(salary) AS total_team_salary
85+
FROM hr.employees
86+
GROUP BY manager_id
87+
ORDER BY total_team_salary DESC
88+
FETCH FIRST 5 ROWS ONLY;
89+
--------------------------------------------------------------------------------
90+
-- HR sees totals; non-HR sees 0 (rows may order differently)
91+
--------------------------------------------------------------------------------
92+
93+
94+
--------------------------------------------------------------------------------
95+
-- 4. Redacting virtual columns in function-based indexes
96+
--------------------------------------------------------------------------------
97+
98+
-- Step 1: Create a function-based index (removes periods and hyphens)
99+
CREATE INDEX hr.phone_number_idx
100+
ON hr.employees(
101+
REPLACE(REPLACE(phone_number, '.', ''), '-', '')
102+
);
103+
104+
-- Step 2: Add a virtual column for rounded salary
105+
ALTER TABLE hr.employees ADD (
106+
rounded_salary AS (ROUND(salary, -3))
107+
);
108+
109+
-- Step 3: Apply redaction to PHONE_NUMBER
110+
BEGIN
111+
DBMS_REDACT.ALTER_POLICY(
112+
object_schema => 'HR',
113+
object_name => 'EMPLOYEES',
114+
column_name => 'PHONE_NUMBER',
115+
policy_name => 'REDACT_DATA',
116+
action => DBMS_REDACT.ADD_COLUMN,
117+
function_type => DBMS_REDACT.FULL
118+
);
119+
END;
120+
/
121+
122+
-- Step 4: Update default redaction values
123+
BEGIN
124+
DBMS_REDACT.UPDATE_FULL_REDACTION_VALUES(
125+
number_value => 0,
126+
char_value => 'X'
127+
);
128+
END;
129+
/
130+
131+
-- Step 5: Query redacted virtual columns
132+
SELECT employee_id, phone_number, rounded_salary
133+
FROM hr.employees
134+
WHERE employee_id IN (101, 103, 176, 201);
135+
--------------------------------------------------------------------------------
136+
137+
138+
--------------------------------------------------------------------------------
139+
-- 5. Redaction in Views with Expressions
140+
--------------------------------------------------------------------------------
141+
142+
-- Step 1: Define a view
143+
CREATE OR REPLACE VIEW hr.employee_view AS
144+
SELECT employee_id AS EMP_ID,
145+
ROUND(MONTHS_BETWEEN(SYSDATE, hire_date)/12) AS YEARS_OF_SERVICE,
146+
CONCAT(UPPER(first_name), ' ', UPPER(last_name)) AS FULL_NAME,
147+
EMAIL
148+
FROM hr.employees;
149+
150+
-- Step 2: Apply redaction to FIRST_NAME
151+
BEGIN
152+
DBMS_REDACT.ALTER_POLICY(
153+
object_schema => 'HR',
154+
object_name => 'EMPLOYEES',
155+
policy_name => 'REDACT_DATA',
156+
column_name => 'FIRST_NAME',
157+
action => DBMS_REDACT.ADD_COLUMN,
158+
function_type => DBMS_REDACT.FULL
159+
);
160+
END;
161+
/
162+
163+
-- Step 3: Apply redaction to EMAIL using regexp
164+
BEGIN
165+
DBMS_REDACT.ALTER_POLICY(
166+
object_schema => 'HR',
167+
object_name => 'EMPLOYEES',
168+
policy_name => 'REDACT_DATA',
169+
column_name => 'EMAIL',
170+
action => DBMS_REDACT.ADD_COLUMN,
171+
function_type => DBMS_REDACT.REGEXP,
172+
regexp_pattern => '^.*$',
173+
regexp_replace_string => 'xxxx@company.com',
174+
regexp_position => 1,
175+
regexp_occurrence => 1,
176+
regexp_match_parameter => 'i'
177+
);
178+
END;
179+
/
180+
181+
-- Step 4: Query the view
182+
SELECT emp_id, years_of_service, full_name, email
183+
FROM hr.employee_view
184+
WHERE emp_id IN (101, 103, 176, 201);
185+
--------------------------------------------------------------------------------
186+
-- HR sees names/emails; non-HR sees X and xxxx@company.com
187+
--------------------------------------------------------------------------------

0 commit comments

Comments
 (0)