forked from docs/doc-exports
Reviewed-by: Hasko, Vladimir <vladimir.hasko@t-systems.com> Co-authored-by: Lu, Huayi <luhuayi@huawei.com> Co-committed-by: Lu, Huayi <luhuayi@huawei.com>
115 lines
19 KiB
HTML
115 lines
19 KiB
HTML
<a name="EN-US_TOPIC_0000001098654774"></a><a name="EN-US_TOPIC_0000001098654774"></a>
|
|
|
|
<h1 class="topictitle1">Data Redaction</h1>
|
|
<div id="body1579504479778"><p id="EN-US_TOPIC_0000001098654774__p16430195117562"><span id="EN-US_TOPIC_0000001098654774__text104300518569">GaussDB(DWS)</span> provides the column-level dynamic data masking (DDM) function. For sensitive data, such as the ID card number, mobile number, and bank card number, the DDM function is used to redact the original data to protect data security and user privacy.</p>
|
|
<ul id="EN-US_TOPIC_0000001098654774__ul1527215710717"><li id="EN-US_TOPIC_0000001098654774__li827214716712">You can create a redaction policy for a specified table object and set the effective scope of the policy. For details, see section "CREATE REDACTION POLICY" in <em id="EN-US_TOPIC_0000001098654774__i18185847132319">SQL Syntax Reference</em>.</li><li id="EN-US_TOPIC_0000001098654774__li16811047591">You can modify a redaction policy using the provided syntax, including modifying expressions for the policy to take effect, renaming the policy, and adding, modifying, and deleting redacted columns. For details, see section "ALTER REDACTION POLICY" in SQL Syntax Reference.</li><li id="EN-US_TOPIC_0000001098654774__li5646129191110">You can delete a redaction policy by deleting data redaction function information of the policy from all columns of a table. For details, see "DROP REDACTION POLICY" in SQL Syntax Reference.</li><li id="EN-US_TOPIC_0000001098654774__li87511974381">You can use the built-in masking functions <strong id="EN-US_TOPIC_0000001098654774__b123940894391215">MASK_NONE</strong>, <strong id="EN-US_TOPIC_0000001098654774__b80228519191215">MASK_FULL</strong>, and <strong id="EN-US_TOPIC_0000001098654774__b597914391215">MASK_PARTIAL</strong>, or create your own masking functions by using PL/pgSQL. For details, see "Data Masking Functions" in <em id="EN-US_TOPIC_0000001098654774__i13702446183316">SQL Syntax Reference</em>.</li><li id="EN-US_TOPIC_0000001098654774__li12636103001512">Redaction policy information is stored in the system catalog <a href="dws_04_0611.html">PG_REDACTION_POLICY</a>, and redacted column information is stored in the system catalog <a href="dws_04_0610.html">PG_REDACTION_COLUMN</a>.</li><li id="EN-US_TOPIC_0000001098654774__li11255133151615">You can view information about the redaction policy and redacted columns in the system views <a href="dws_04_0858.html">REDACTION_POLICIES</a> and <a href="dws_04_0857.html">REDACTION_COLUMNS</a>.</li></ul>
|
|
<div class="note" id="EN-US_TOPIC_0000001098654774__nf3dbb0444a8445728f3cc175b020f37a"><img src="public_sys-resources/note_3.0-en-us.png"><span class="notetitle"> </span><div class="notebody"><ul id="EN-US_TOPIC_0000001098654774__u4c212b5c9b0649438fb48786a5a38e07"><li id="EN-US_TOPIC_0000001098654774__li631681924917">Generally, you can execute a <strong id="EN-US_TOPIC_0000001098654774__b14277840192813">SELECT</strong> statement to view the data redaction result. If the statement has the following features, sensitive data may be deliberately obtained. In this case, an error will be reported during statement execution.<ul id="EN-US_TOPIC_0000001098654774__ul17277182464915"><li id="EN-US_TOPIC_0000001098654774__li9011395587">The <strong id="EN-US_TOPIC_0000001098654774__b16145133112293">GROUP BY</strong> clause references a <strong id="EN-US_TOPIC_0000001098654774__b103069416305">Target Entry</strong> that contains redacted columns as the target column.</li><li id="EN-US_TOPIC_0000001098654774__li1358741045920">The <strong id="EN-US_TOPIC_0000001098654774__b1392532143111">DISTINCT</strong> clause is executed on the output redacted columns.</li><li id="EN-US_TOPIC_0000001098654774__li2992173495911">The statement contains <strong id="EN-US_TOPIC_0000001098654774__b10578133617312">CTE</strong>.</li><li id="EN-US_TOPIC_0000001098654774__li159401759175919">Set operations are involved.</li><li id="EN-US_TOPIC_0000001098654774__li2078104618019">The target columns of a subquery are not redacted columns of the base table, but are the expressions or function calls for the redacted columns of the base table.</li></ul>
|
|
</li><li id="EN-US_TOPIC_0000001098654774__li21764151492">You can use <strong id="EN-US_TOPIC_0000001098654774__b278291592113">COPY TO</strong> or GDS to export the redacted data. As the redacted data is irreversible, any secondary operation on the redacted data is meaningless.</li><li id="EN-US_TOPIC_0000001098654774__li1917621534918">The target columns of <strong id="EN-US_TOPIC_0000001098654774__b95271437153510">UPDATE</strong>, <strong id="EN-US_TOPIC_0000001098654774__b6315194133513">MERGE INTO</strong>, and <strong id="EN-US_TOPIC_0000001098654774__b1912184511354">DELETE</strong> statements cannot contain redacted columns.</li><li id="EN-US_TOPIC_0000001098654774__li1196526615">The <strong id="EN-US_TOPIC_0000001098654774__b682616511756">UPSERT</strong> statement allows you to update data using <strong id="EN-US_TOPIC_0000001098654774__b18305192213713">EXCLUDED</strong>. If data in the base table is updated by referencing redacted columns, the data may be modified by mistake. As a result, an error will be reported during the execution.</li></ul>
|
|
</div></div>
|
|
<div class="section" id="EN-US_TOPIC_0000001098654774__section3980155135417"><h4 class="sectiontitle">Examples</h4><p id="EN-US_TOPIC_0000001098654774__p10632108121811">The following uses the employee table <strong id="EN-US_TOPIC_0000001098654774__b12177185534618">emp</strong>, administrator <strong id="EN-US_TOPIC_0000001098654774__b152031658154611">alice</strong>, and common users <strong id="EN-US_TOPIC_0000001098654774__b180615174717">matu</strong> and <strong id="EN-US_TOPIC_0000001098654774__b1912414164718">july</strong> as examples to describe the data redaction process. The user <strong id="EN-US_TOPIC_0000001098654774__b3857224162717">alice</strong> is the owner of the <strong id="EN-US_TOPIC_0000001098654774__b073842918275">emp</strong> table. The <strong id="EN-US_TOPIC_0000001098654774__b1074718364275">emp</strong> table contains private data such as the employee name, mobile number, email address, bank card number, and salary.</p>
|
|
<ol id="EN-US_TOPIC_0000001098654774__ol879392613278"><li id="EN-US_TOPIC_0000001098654774__li127936267279">Create users <strong id="EN-US_TOPIC_0000001098654774__b0677125813271">alice</strong>, <strong id="EN-US_TOPIC_0000001098654774__b6685165814270">matu</strong>, and <strong id="EN-US_TOPIC_0000001098654774__b2135296138">july</strong>:<pre class="screen" id="EN-US_TOPIC_0000001098654774__screen11620108193211">CREATE ROLE alice PASSWORD '<em id="EN-US_TOPIC_0000001098654774__i99347212712">password</em>';
|
|
CREATE ROLE matu PASSWORD '<em id="EN-US_TOPIC_0000001098654774__i49091211811">password</em>';
|
|
CREATE ROLE july PASSWORD '<em id="EN-US_TOPIC_0000001098654774__i1193112413813">password</em>';</pre>
|
|
</li><li id="EN-US_TOPIC_0000001098654774__li1894811133113">Create the <strong id="EN-US_TOPIC_0000001098654774__b1481762792811">emp</strong> table as user <strong id="EN-US_TOPIC_0000001098654774__b10575143132819">alice</strong>, and insert three employee records into the table.<pre class="screen" id="EN-US_TOPIC_0000001098654774__screen15431744183519">CREATE TABLE emp(id int, name varchar(20), phone_no varchar(11), card_no number, card_string varchar(19), email text, salary numeric(100, 4), birthday date);
|
|
|
|
INSERT INTO emp VALUES(1, 'anny', '13420002340', 1234123412341234, '1234-1234-1234-1234', 'smithWu@163.com', 10000.00, '1999-10-02');
|
|
INSERT INTO emp VALUES(2, 'bob', '18299023211', 3456345634563456, '3456-3456-3456-3456', '66allen_mm@qq.com', 9999.99, '1989-12-12');
|
|
INSERT INTO emp VALUES(3, 'cici', '15512231233', NULL, NULL, 'jonesishere@sina.com', NULL, '1992-11-06');</pre>
|
|
</li><li id="EN-US_TOPIC_0000001098654774__li993218359278">User <strong id="EN-US_TOPIC_0000001098654774__b19876142233719">alice</strong> grants the <strong id="EN-US_TOPIC_0000001098654774__b10672932183715">emp</strong> table read permission to users <strong id="EN-US_TOPIC_0000001098654774__b1132551193713">matu</strong> and <strong id="EN-US_TOPIC_0000001098654774__b1827557370">july</strong>.<pre class="screen" id="EN-US_TOPIC_0000001098654774__screen1369242365419">GRANT SELECT ON emp TO matu, july;</pre>
|
|
</li><li id="EN-US_TOPIC_0000001098654774__li169422031114411">Only user <strong id="EN-US_TOPIC_0000001098654774__b19373827193819">alice</strong> can view all employee information. Users <strong id="EN-US_TOPIC_0000001098654774__b14351115414389">matu</strong> and <strong id="EN-US_TOPIC_0000001098654774__b676055653812">july</strong> cannot view bank card numbers and salary data of the employees. Create a redaction policy for the <strong id="EN-US_TOPIC_0000001098654774__b1520813616496">emp</strong> table and bind the redaction function to <strong id="EN-US_TOPIC_0000001098654774__b4719135124914">card_no</strong>, <strong id="EN-US_TOPIC_0000001098654774__b1592911379498">card_string</strong>, and <strong id="EN-US_TOPIC_0000001098654774__b129861242174918">salary</strong> columns, respectively.<pre class="screen" id="EN-US_TOPIC_0000001098654774__screen17499175311549">CREATE REDACTION POLICY mask_emp ON emp WHEN (current_user IN ('matu', 'july'))
|
|
ADD COLUMN card_no WITH mask_full(card_no),
|
|
ADD COLUMN card_string WITH mask_partial(card_string, 'VVVVFVVVVFVVVVFVVVV','VVVV-VVVV-VVVV-VVVV','#',1,12),
|
|
ADD COLUMN salary WITH mask_partial(salary, '9', 1, length(salary) - 2);</pre>
|
|
</li><li id="EN-US_TOPIC_0000001098654774__li85821198540">Switch to users <strong id="EN-US_TOPIC_0000001098654774__b4868192215510">matu</strong> and <strong id="EN-US_TOPIC_0000001098654774__b1273562465511">july</strong> and view the <strong id="EN-US_TOPIC_0000001098654774__b17465133514558">emp</strong> table, respectively.<pre class="screen" id="EN-US_TOPIC_0000001098654774__screen14681113715216">SET ROLE matu PASSWORD '<em id="EN-US_TOPIC_0000001098654774__i9769151719820">password</em>';
|
|
SELECT * FROM emp;
|
|
id | name | phone_no | card_no | card_string | email | salary | birthday
|
|
----+------+-------------+---------+---------------------+----------------------+------------+---------------------
|
|
1 | anny | 13420002340 | 0 | ####-####-####-1234 | smithWu@163.com | 99999.9990 | 1999-10-02 00:00:00
|
|
2 | bob | 18299023211 | 0 | ####-####-####-3456 | 66allen_mm@qq.com | 9999.9990 | 1989-12-12 00:00:00
|
|
3 | cici | 15512231233 | | | jonesishere@sina.com | | 1992-11-06 00:00:00
|
|
(3 rows)
|
|
|
|
SET ROLE july PASSWORD '<em id="EN-US_TOPIC_0000001098654774__i1168619262082">password</em>';
|
|
SELECT * FROM emp;
|
|
id | name | phone_no | card_no | card_string | email | salary | birthday
|
|
----+------+-------------+---------+---------------------+----------------------+------------+---------------------
|
|
1 | anny | 13420002340 | 0 | ####-####-####-1234 | smithWu@163.com | 99999.9990 | 1999-10-02 00:00:00
|
|
2 | bob | 18299023211 | 0 | ####-####-####-3456 | 66allen_mm@qq.com | 9999.9990 | 1989-12-12 00:00:00
|
|
3 | cici | 15512231233 | | | jonesishere@sina.com | | 1992-11-06 00:00:00
|
|
(3 rows)</pre>
|
|
</li><li id="EN-US_TOPIC_0000001098654774__li19924163019210">User <strong id="EN-US_TOPIC_0000001098654774__b106938260569">matu</strong> also has the permission for viewing all employee information, but user <strong id="EN-US_TOPIC_0000001098654774__b16933238125613">july</strong> does not. Modify the effective scope of the redaction policy.<pre class="screen" id="EN-US_TOPIC_0000001098654774__screen18588143213155">ALTER REDACTION POLICY mask_emp ON emp WHEN(current_user = 'july');</pre>
|
|
</li><li id="EN-US_TOPIC_0000001098654774__li199211269151">Switch to users <strong id="EN-US_TOPIC_0000001098654774__b657317100813">matu</strong> and <strong id="EN-US_TOPIC_0000001098654774__b45742109818">july</strong> and view the <strong id="EN-US_TOPIC_0000001098654774__b1857520104820">emp</strong> table again, respectively.<pre class="screen" id="EN-US_TOPIC_0000001098654774__screen1198815014174">SET ROLE matu PASSWORD '<em id="EN-US_TOPIC_0000001098654774__i1642173313813">password</em>';
|
|
SELECT * FROM emp;
|
|
id | name | phone_no | card_no | card_string | email | salary | birthday
|
|
----+------+-------------+------------------+---------------------+----------------------+------------+---------------------
|
|
1 | anny | 13420002340 | 1234123412341234 | 1234-1234-1234-1234 | smithWu@163.com | 10000.0000 | 1999-10-02 00:00:00
|
|
2 | bob | 18299023211 | 3456345634563456 | 3456-3456-3456-3456 | 66allen_mm@qq.com | 9999.9900 | 1989-12-12 00:00:00
|
|
3 | cici | 15512231233 | | | jonesishere@sina.com | | 1992-11-06 00:00:00
|
|
(3 rows)
|
|
|
|
SET ROLE july PASSWORD '<em id="EN-US_TOPIC_0000001098654774__i12874441389">password</em>';
|
|
SELECT * FROM emp;
|
|
id | name | phone_no | card_no | card_string | email | salary | birthday
|
|
----+------+-------------+---------+---------------------+----------------------+------------+---------------------
|
|
1 | anny | 13420002340 | 0 | ####-####-####-1234 | smithWu@163.com | 99999.9990 | 1999-10-02 00:00:00
|
|
2 | bob | 18299023211 | 0 | ####-####-####-3456 | 66allen_mm@qq.com | 9999.9990 | 1989-12-12 00:00:00
|
|
3 | cici | 15512231233 | | | jonesishere@sina.com | | 1992-11-06 00:00:00
|
|
(3 rows)</pre>
|
|
</li><li id="EN-US_TOPIC_0000001098654774__li19320174871611">The information in the <strong id="EN-US_TOPIC_0000001098654774__b19502146103214">phone_no</strong>, <strong id="EN-US_TOPIC_0000001098654774__b1367944816327">email</strong>, and <strong id="EN-US_TOPIC_0000001098654774__b1572813505324">birthday</strong> columns is private data. Update the redaction policy <strong id="EN-US_TOPIC_0000001098654774__b15134288113">mask_emp</strong> and add three redacted columns.<pre class="screen" id="EN-US_TOPIC_0000001098654774__screen159991742131918">ALTER REDACTION POLICY mask_emp ON emp ADD COLUMN phone_no WITH mask_partial(phone_no, '*', 4);
|
|
ALTER REDACTION POLICY mask_emp ON emp ADD COLUMN email WITH mask_partial(email, '*', 1, position('@' in email));
|
|
ALTER REDACTION POLICY mask_emp ON emp ADD COLUMN birthday WITH mask_full(birthday);</pre>
|
|
</li><li id="EN-US_TOPIC_0000001098654774__li13706377194">Switch to user <strong id="EN-US_TOPIC_0000001098654774__b10690121412125">july</strong> and view the <strong id="EN-US_TOPIC_0000001098654774__b631210191125">emp</strong> table data.<pre class="screen" id="EN-US_TOPIC_0000001098654774__screen11486103252310">SET ROLE july PASSWORD '<em id="EN-US_TOPIC_0000001098654774__i12583231792">password</em>';
|
|
SELECT * FROM emp;
|
|
id | name | phone_no | card_no | card_string | email | salary | birthday
|
|
----+------+-------------+---------+---------------------+----------------------+------------+---------------------
|
|
1 | anny | 134******** | 0 | ####-####-####-1234 | ********163.com | 99999.9990 | 1970-01-01 00:00:00
|
|
2 | bob | 182******** | 0 | ####-####-####-3456 | ***********qq.com | 9999.9990 | 1970-01-01 00:00:00
|
|
3 | cici | 155******** | | | ************sina.com | | 1970-01-01 00:00:00
|
|
(3 rows)</pre>
|
|
</li><li id="EN-US_TOPIC_0000001098654774__li1248562232318">Query <strong id="EN-US_TOPIC_0000001098654774__b12101759131218">redaction_policies</strong> and <strong id="EN-US_TOPIC_0000001098654774__b8697141171316">redaction_columns</strong> to view details about the current redaction policy <strong id="EN-US_TOPIC_0000001098654774__b668113203137">mask_emp</strong>.<pre class="screen" id="EN-US_TOPIC_0000001098654774__screen2792112611256">SELECT * FROM redaction_policies;
|
|
object_schema | object_owner | object_name | policy_name | expression | enable | policy_description
|
|
---------------+--------------+-------------+-------------+-----------------------------------+--------+--------------------
|
|
public | alice | emp | mask_emp | ("current_user"() = 'july'::name) | t |
|
|
(1 row)
|
|
|
|
SELECT object_name, column_name, function_info FROM redaction_columns;
|
|
object_name | column_name | function_info
|
|
-------------+-------------+-------------------------------------------------------------------------------------------------------
|
|
emp | card_no | mask_full(card_no)
|
|
emp | card_string | mask_partial(card_string, 'VVVVFVVVVFVVVVFVVVV'::text, 'VVVV-VVVV-VVVV-VVVV'::text, '#'::text, 1, 12)
|
|
emp | email | mask_partial(email, '*'::text, 1, "position"(email, '@'::text))
|
|
emp | salary | mask_partial(salary, '9'::text, 1, (length((salary)::text) - 2))
|
|
emp | birthday | mask_full(birthday)
|
|
emp | phone_no | mask_partial(phone_no, '*'::text, 4)
|
|
(6 rows)</pre>
|
|
</li><li id="EN-US_TOPIC_0000001098654774__li160143114418">Add the <strong id="EN-US_TOPIC_0000001098654774__b64504243091215">salary_info</strong> column. To replace the salary information in text format with *.*, you can create a user-defined redaction function. In this step, you can use the PL/pgSQL to define the redaction function <strong id="EN-US_TOPIC_0000001098654774__b88549896891215">mask_regexp_salary</strong>. To create a redaction column, you simply need to customize the function name and parameter list. For details, see <a href="dws_04_0507.html">User-Defined Functions</a>.<pre class="screen" id="EN-US_TOPIC_0000001098654774__screen10991143155318">ALTER TABLE emp ADD COLUMN salary_info TEXT;
|
|
UPDATE emp SET salary_info = salary::text;
|
|
|
|
CREATE FUNCTION mask_regexp_salary(salary_info text) RETURNS text AS
|
|
$$
|
|
SELECT regexp_replace($1, '[0-9]+','*','g');
|
|
$$
|
|
LANGUAGE SQL
|
|
STRICT SHIPPABLE;
|
|
|
|
ALTER REDACTION POLICY mask_emp ON emp ADD COLUMN salary_info WITH mask_regexp_salary(salary_info);
|
|
|
|
SET ROLE july PASSWORD '<em id="EN-US_TOPIC_0000001098654774__i9804811998">password</em>';
|
|
SELECT id, name, salary_info FROM emp;
|
|
id | name | salary_info
|
|
----+------+-------------
|
|
1 | anny | *.*
|
|
2 | bob | *.*
|
|
3 | cici |
|
|
(3 rows)</pre>
|
|
</li><li id="EN-US_TOPIC_0000001098654774__li167771414112519">If there is no need to set a redaction policy for the <strong id="EN-US_TOPIC_0000001098654774__b678491013155">emp</strong> table, delete the redaction policy <strong id="EN-US_TOPIC_0000001098654774__b1923918242150">mask_emp</strong>.<pre class="screen" id="EN-US_TOPIC_0000001098654774__screen13384194062820">DROP REDACTION POLICY mask_emp ON emp;</pre>
|
|
</li></ol>
|
|
</div>
|
|
</div>
|
|
<div>
|
|
<div class="familylinks">
|
|
<div class="parentlink"><strong>Parent topic:</strong> <a href="dws_04_0994.html">Sensitive Data Management</a></div>
|
|
</div>
|
|
</div>
|
|
|