쿠키 기본 설정 선택

당사는 사이트와 서비스를 제공하는 데 필요한 필수 쿠키 및 유사한 도구를 사용합니다. 고객이 사이트를 어떻게 사용하는지 파악하고 개선할 수 있도록 성능 쿠키를 사용해 익명의 통계를 수집합니다. 필수 쿠키는 비활성화할 수 없지만 '사용자 지정' 또는 ‘거부’를 클릭하여 성능 쿠키를 거부할 수 있습니다.

사용자가 동의하는 경우 AWS와 승인된 제3자도 쿠키를 사용하여 유용한 사이트 기능을 제공하고, 사용자의 기본 설정을 기억하고, 관련 광고를 비롯한 관련 콘텐츠를 표시합니다. 필수가 아닌 모든 쿠키를 수락하거나 거부하려면 ‘수락’ 또는 ‘거부’를 클릭하세요. 더 자세한 내용을 선택하려면 ‘사용자 정의’를 클릭하세요.

행 수준 보안 엔드 투 엔드 예제 - Amazon Redshift

행 수준 보안 엔드 투 엔드 예제

다음은 수퍼유저가 몇 가지 사용자와 역할을 만드는 방법을 보여주는 자세한 예입니다. 그러면 secadmin 역할이 부여된 사용자가 RLS 정책을 생성, 연결, 분리 및 삭제합니다. 이 예에서는 tickit 샘플 데이터베이스를 사용합니다. 자세한 내용은 Amazon Redshift 시작 안내서Amazon S3에서 Amazon Redshift로 데이터 로드를 참조하세요.

-- Create users and roles referenced in the policy statements. CREATE ROLE analyst; CREATE ROLE consumer; CREATE ROLE dbadmin; CREATE ROLE auditor; CREATE USER bob WITH PASSWORD 'Name_is_bob_1'; CREATE USER alice WITH PASSWORD 'Name_is_alice_1'; CREATE USER joe WITH PASSWORD 'Name_is_joe_1'; CREATE USER molly WITH PASSWORD 'Name_is_molly_1'; CREATE USER bruce WITH PASSWORD 'Name_is_bruce_1'; GRANT ROLE sys:secadmin TO bob; GRANT ROLE analyst TO alice; GRANT ROLE consumer TO joe; GRANT ROLE dbadmin TO molly; GRANT ROLE auditor TO bruce; GRANT ALL ON TABLE tickit_category_redshift TO PUBLIC; GRANT ALL ON TABLE tickit_sales_redshift TO PUBLIC; GRANT ALL ON TABLE tickit_event_redshift TO PUBLIC; -- Create table and schema referenced in the policy statements. CREATE SCHEMA target_schema; GRANT ALL ON SCHEMA target_schema TO PUBLIC; CREATE TABLE target_schema.target_event_table (LIKE tickit_event_redshift); GRANT ALL ON TABLE target_schema.target_event_table TO PUBLIC; -- Change session to analyst alice. SET SESSION AUTHORIZATION alice; -- Check the tuples visible to analyst alice. -- Should contain all 3 categories. SELECT catgroup, count(*) FROM tickit_category_redshift GROUP BY catgroup ORDER BY catgroup; -- Change session to security administrator bob. SET SESSION AUTHORIZATION bob; CREATE RLS POLICY policy_concerts WITH (catgroup VARCHAR(10)) USING (catgroup = 'Concerts'); SELECT poldb, polname, polalias, polatts, polqual, polenabled, polmodifiedby FROM svv_rls_policy WHERE poldb = CURRENT_DATABASE(); ATTACH RLS POLICY policy_concerts ON tickit_category_redshift TO ROLE analyst, ROLE dbadmin; ALTER TABLE tickit_category_redshift ROW LEVEL SECURITY ON; SELECT * FROM svv_rls_attached_policy; -- Change session to analyst alice. SET SESSION AUTHORIZATION alice; -- Check that tuples with only `Concert` category will be visible to analyst alice. SELECT catgroup, count(*) FROM tickit_category_redshift GROUP BY catgroup ORDER BY catgroup; -- Change session to consumer joe. SET SESSION AUTHORIZATION joe; -- Although the policy is attached to a different role, no tuples will be -- visible to consumer joe because the default deny all policy is applied. SELECT catgroup, count(*) FROM tickit_category_redshift GROUP BY catgroup ORDER BY catgroup; -- Change session to dbadmin molly. SET SESSION AUTHORIZATION molly; -- Check that tuples with only `Concert` category will be visible to dbadmin molly. SELECT catgroup, count(*) FROM tickit_category_redshift GROUP BY catgroup ORDER BY catgroup; -- Check that EXPLAIN output contains RLS SecureScan to prevent disclosure of -- sensitive information such as RLS filters. EXPLAIN SELECT catgroup, count(*) FROM tickit_category_redshift GROUP BY catgroup ORDER BY catgroup; -- Change session to security administrator bob. SET SESSION AUTHORIZATION bob; -- Grant IGNORE RLS permission so that RLS policies do not get applicable to role dbadmin. GRANT IGNORE RLS TO ROLE dbadmin; -- Grant EXPLAIN RLS permission so that anyone in role auditor can view complete EXPLAIN output. GRANT EXPLAIN RLS TO ROLE auditor; -- Change session to dbadmin molly. SET SESSION AUTHORIZATION molly; -- Check that all tuples are visible to dbadmin molly because `IGNORE RLS` is granted to role dbadmin. SELECT catgroup, count(*) FROM tickit_category_redshift GROUP BY catgroup ORDER BY catgroup; -- Change session to auditor bruce. SET SESSION AUTHORIZATION bruce; -- Check explain plan is visible to auditor bruce because `EXPLAIN RLS` is granted to role auditor. EXPLAIN SELECT catgroup, count(*) FROM tickit_category_redshift GROUP BY catgroup ORDER BY catgroup; -- Change session to security administrator bob. SET SESSION AUTHORIZATION bob; DETACH RLS POLICY policy_concerts ON tickit_category_redshift FROM ROLE analyst, ROLE dbadmin; -- Change session to analyst alice. SET SESSION AUTHORIZATION alice; -- Check that no tuples are visible to analyst alice. -- Although the policy is detached, no tuples will be visible to analyst alice -- because of default deny all policy is applied if the table has RLS on. SELECT catgroup, count(*) FROM tickit_category_redshift GROUP BY catgroup ORDER BY catgroup; -- Change session to security administrator bob. SET SESSION AUTHORIZATION bob; CREATE RLS POLICY policy_events WITH (eventid INTEGER) AS ev USING ( ev.eventid IN (SELECT eventid FROM tickit_sales_redshift WHERE qtysold <3) ); ATTACH RLS POLICY policy_events ON tickit_event_redshift TO ROLE analyst; ATTACH RLS POLICY policy_events ON target_schema.target_event_table TO ROLE consumer; RESET SESSION AUTHORIZATION; -- Can not cannot alter type of dependent column. ALTER TABLE target_schema.target_event_table ALTER COLUMN eventid TYPE float; ALTER TABLE tickit_event_redshift ALTER COLUMN eventid TYPE float; ALTER TABLE tickit_sales_redshift ALTER COLUMN eventid TYPE float; ALTER TABLE tickit_sales_redshift ALTER COLUMN qtysold TYPE float; -- Can not cannot rename dependent column. ALTER TABLE target_schema.target_event_table RENAME COLUMN eventid TO renamed_eventid; ALTER TABLE tickit_event_redshift RENAME COLUMN eventid TO renamed_eventid; ALTER TABLE tickit_sales_redshift RENAME COLUMN eventid TO renamed_eventid; ALTER TABLE tickit_sales_redshift RENAME COLUMN qtysold TO renamed_qtysold; -- Can not drop dependent column. ALTER TABLE target_schema.target_event_table DROP COLUMN eventid CASCADE; ALTER TABLE tickit_event_redshift DROP COLUMN eventid CASCADE; ALTER TABLE tickit_sales_redshift DROP COLUMN eventid CASCADE; ALTER TABLE tickit_sales_redshift DROP COLUMN qtysold CASCADE; -- Can not drop lookup table. DROP TABLE tickit_sales_redshift CASCADE; -- Change session to security administrator bob. SET SESSION AUTHORIZATION bob; DROP RLS POLICY policy_concerts; DROP RLS POLICY IF EXISTS policy_events; ALTER TABLE tickit_category_redshift ROW LEVEL SECURITY OFF; RESET SESSION AUTHORIZATION; -- Drop users and roles. DROP USER bob; DROP USER alice; DROP USER joe; DROP USER molly; DROP USER bruce; DROP ROLE analyst; DROP ROLE consumer; DROP ROLE auditor FORCE; DROP ROLE dbadmin FORCE;
프라이버시사이트 이용 약관쿠키 기본 설정
© 2025, Amazon Web Services, Inc. 또는 계열사. All rights reserved.