diff --git a/Makefile b/Makefile index ffad7d6af..4cd623484 100644 --- a/Makefile +++ b/Makefile @@ -113,7 +113,8 @@ REGRESS = scan \ jsonb_operators \ list_comprehension \ map_projection \ - direct_field_access + direct_field_access \ + security ifneq ($(EXTRA_TESTS),) REGRESS += $(EXTRA_TESTS) diff --git a/regress/expected/security.out b/regress/expected/security.out new file mode 100644 index 000000000..59e58cb05 --- /dev/null +++ b/regress/expected/security.out @@ -0,0 +1,1657 @@ +/* + * Licensed to the Apache Software Foundation (ASF) under one + * or more contributor license agreements. See the NOTICE file + * distributed with this work for additional information + * regarding copyright ownership. The ASF licenses this file + * to you under the Apache License, Version 2.0 (the + * "License"); you may not use this file except in compliance + * with the License. You may obtain a copy of the License at + * + * http://www.apache.org/licenses/LICENSE-2.0 + * + * Unless required by applicable law or agreed to in writing, + * software distributed under the License is distributed on an + * "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY + * KIND, either express or implied. See the License for the + * specific language governing permissions and limitations + * under the License. + */ +LOAD 'age'; +SET search_path TO ag_catalog; +-- +-- Test Privileges +-- +-- +-- Setup: Create test graph and data as superuser +-- +SELECT create_graph('security_test'); +NOTICE: graph "security_test" has been created + create_graph +-------------- + +(1 row) + +-- Create test vertices +SELECT * FROM cypher('security_test', $$ + CREATE (:Person {name: 'Alice', age: 30}) +$$) AS (a agtype); + a +--- +(0 rows) + +SELECT * FROM cypher('security_test', $$ + CREATE (:Person {name: 'Bob', age: 25}) +$$) AS (a agtype); + a +--- +(0 rows) + +SELECT * FROM cypher('security_test', $$ + CREATE (:Document {title: 'Secret', content: 'classified'}) +$$) AS (a agtype); + a +--- +(0 rows) + +-- Create test edges +SELECT * FROM cypher('security_test', $$ + MATCH (a:Person {name: 'Alice'}), (b:Person {name: 'Bob'}) + CREATE (a)-[:KNOWS {since: 2020}]->(b) +$$) AS (a agtype); + a +--- +(0 rows) + +SELECT * FROM cypher('security_test', $$ + MATCH (a:Person {name: 'Alice'}), (d:Document) + CREATE (a)-[:OWNS]->(d) +$$) AS (a agtype); + a +--- +(0 rows) + +-- +-- Create test roles with different permission levels +-- +-- Role with only SELECT (read-only) +CREATE ROLE security_test_readonly LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_readonly; +GRANT SELECT ON ALL TABLES IN SCHEMA security_test TO security_test_readonly; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_readonly; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_readonly; +-- Role with SELECT and INSERT +CREATE ROLE security_test_insert LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_insert; +GRANT SELECT, INSERT ON ALL TABLES IN SCHEMA security_test TO security_test_insert; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_insert; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_insert; +-- Grant sequence usage for ID generation +GRANT USAGE ON ALL SEQUENCES IN SCHEMA security_test TO security_test_insert; +-- Role with SELECT and UPDATE +CREATE ROLE security_test_update LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_update; +GRANT SELECT, UPDATE ON ALL TABLES IN SCHEMA security_test TO security_test_update; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_update; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_update; +-- Role with SELECT and DELETE +CREATE ROLE security_test_delete LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_delete; +GRANT SELECT, DELETE ON ALL TABLES IN SCHEMA security_test TO security_test_delete; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_delete; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_delete; +CREATE ROLE security_test_detach_delete LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_detach_delete; +GRANT SELECT ON ALL TABLES IN SCHEMA security_test TO security_test_detach_delete; +GRANT DELETE ON security_test."Person" TO security_test_detach_delete; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_detach_delete; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_detach_delete; +-- Role with all permissions +CREATE ROLE security_test_full LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_full; +GRANT ALL ON ALL TABLES IN SCHEMA security_test TO security_test_full; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_full; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_full; +GRANT USAGE ON ALL SEQUENCES IN SCHEMA security_test TO security_test_full; +-- Role with NO SELECT on graph tables (to test read failures) +CREATE ROLE security_test_noread LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_noread; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_noread; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_noread; +-- No SELECT on security_test tables +-- ============================================================================ +-- PART 1: SELECT Permission Tests - Failure Cases (No Read Permission) +-- ============================================================================ +SET ROLE security_test_noread; +-- Test: MATCH on vertices should fail without SELECT permission +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person) RETURN p.name +$$) AS (name agtype); +ERROR: permission denied for table Person +-- Test: MATCH on edges should fail without SELECT permission +SELECT * FROM cypher('security_test', $$ + MATCH ()-[k:KNOWS]->() RETURN k +$$) AS (k agtype); +ERROR: permission denied for table _ag_label_vertex +-- Test: MATCH with path should fail +SELECT * FROM cypher('security_test', $$ + MATCH (a)-[e]->(b) RETURN a, e, b +$$) AS (a agtype, e agtype, b agtype); +ERROR: permission denied for table _ag_label_vertex +RESET ROLE; +-- Create role with SELECT only on base label tables, not child labels +-- NOTE: PostgreSQL inheritance allows access to child table rows when querying +-- through a parent table. This is expected behavior - SELECT on _ag_label_vertex +-- allows reading all vertices (including Person, Document) via inheritance. +CREATE ROLE security_test_base_only LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_base_only; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_base_only; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_base_only; +-- Only grant SELECT on base tables, NOT on Person, Document, KNOWS, OWNS +GRANT SELECT ON security_test._ag_label_vertex TO security_test_base_only; +GRANT SELECT ON security_test._ag_label_edge TO security_test_base_only; +SET ROLE security_test_base_only; +-- Test: MATCH (n) succeeds because PostgreSQL inheritance allows access to child rows +-- when querying through parent table. Permission on _ag_label_vertex grants read +-- access to all vertices via inheritance hierarchy. +SELECT * FROM cypher('security_test', $$ + MATCH (n) RETURN n +$$) AS (n agtype); + n +------------------------------------------------------------------------------------------------------------------- + {"id": 844424930131969, "label": "Person", "properties": {"age": 30, "name": "Alice"}}::vertex + {"id": 844424930131970, "label": "Person", "properties": {"age": 25, "name": "Bob"}}::vertex + {"id": 1125899906842625, "label": "Document", "properties": {"title": "Secret", "content": "classified"}}::vertex +(3 rows) + +-- Test: MATCH ()-[e]->() succeeds via inheritance (same reason as above) +SELECT * FROM cypher('security_test', $$ + MATCH ()-[e]->() RETURN e +$$) AS (e agtype); + e +----------------------------------------------------------------------------------------------------------------------------------------- + {"id": 1407374883553281, "label": "KNOWS", "end_id": 844424930131970, "start_id": 844424930131969, "properties": {"since": 2020}}::edge + {"id": 1688849860263937, "label": "OWNS", "end_id": 1125899906842625, "start_id": 844424930131969, "properties": {}}::edge +(2 rows) + +-- ============================================================================ +-- PART 2: SELECT Permission Tests - Success Cases (Read-Only Role) +-- ============================================================================ +RESET ROLE; +SET ROLE security_test_readonly; +-- Test: MATCH should succeed with SELECT permission +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + name +--------- + "Alice" + "Bob" +(2 rows) + +-- Test: MATCH with edges should succeed +SELECT * FROM cypher('security_test', $$ + MATCH (a:Person)-[k:KNOWS]->(b:Person) + RETURN a.name, b.name +$$) AS (a agtype, b agtype); + a | b +---------+------- + "Alice" | "Bob" +(1 row) + +-- Test: MATCH across multiple labels should succeed +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person)-[:OWNS]->(d:Document) + RETURN p.name, d.title +$$) AS (person agtype, doc agtype); + person | doc +---------+---------- + "Alice" | "Secret" +(1 row) + +-- ============================================================================ +-- PART 3: INSERT Permission Tests (CREATE clause) +-- ============================================================================ +-- Test: CREATE should fail with only SELECT permission +SELECT * FROM cypher('security_test', $$ + CREATE (:Person {name: 'Charlie'}) +$$) AS (a agtype); +ERROR: permission denied for table Person +-- Test: CREATE edge should fail +SELECT * FROM cypher('security_test', $$ + MATCH (a:Person {name: 'Alice'}), (b:Person {name: 'Bob'}) + CREATE (a)-[:FRIENDS]->(b) +$$) AS (a agtype); +ERROR: permission denied for schema security_test +LINE 1: SELECT * FROM cypher('security_test', $$ + ^ +RESET ROLE; +SET ROLE security_test_insert; +-- Test: CREATE vertex should succeed with INSERT permission +SELECT * FROM cypher('security_test', $$ + CREATE (:Person {name: 'Charlie', age: 35}) +$$) AS (a agtype); + a +--- +(0 rows) + +-- Test: CREATE edge should succeed with INSERT permission +SELECT * FROM cypher('security_test', $$ + MATCH (a:Person {name: 'Charlie'}), (b:Person {name: 'Alice'}) + CREATE (a)-[:KNOWS {since: 2023}]->(b) +$$) AS (a agtype); + a +--- +(0 rows) + +-- Verify the inserts worked +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Charlie'}) RETURN p.name, p.age +$$) AS (name agtype, age agtype); + name | age +-----------+----- + "Charlie" | 35 +(1 row) + +-- ============================================================================ +-- PART 4: UPDATE Permission Tests (SET clause) +-- ============================================================================ +RESET ROLE; +SET ROLE security_test_readonly; +-- Test: SET should fail with only SELECT permission +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Alice'}) + SET p.age = 31 + RETURN p +$$) AS (p agtype); +ERROR: permission denied for table Person +-- Test: SET on edge should fail +SELECT * FROM cypher('security_test', $$ + MATCH ()-[k:KNOWS]->() + SET k.since = 2021 + RETURN k +$$) AS (k agtype); +ERROR: permission denied for table KNOWS +RESET ROLE; +SET ROLE security_test_update; +-- Test: SET should succeed with UPDATE permission +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Alice'}) + SET p.age = 31 + RETURN p.name, p.age +$$) AS (name agtype, age agtype); + name | age +---------+----- + "Alice" | 31 +(1 row) + +-- Test: SET on edge should succeed +SELECT * FROM cypher('security_test', $$ + MATCH (a:Person {name: 'Alice'})-[k:KNOWS]->(b:Person {name: 'Bob'}) + SET k.since = 2019 + RETURN k.since +$$) AS (since agtype); + since +------- + 2019 +(1 row) + +-- Test: SET with map update should succeed +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Bob'}) + SET p += {hobby: 'reading'} + RETURN p.name, p.hobby +$$) AS (name agtype, hobby agtype); + name | hobby +-------+----------- + "Bob" | "reading" +(1 row) + +-- ============================================================================ +-- PART 5: UPDATE Permission Tests (REMOVE clause) +-- ============================================================================ +RESET ROLE; +SET ROLE security_test_readonly; +-- Test: REMOVE should fail with only SELECT permission +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Bob'}) + REMOVE p.hobby + RETURN p +$$) AS (p agtype); +ERROR: permission denied for table Person +RESET ROLE; +SET ROLE security_test_update; +-- Test: REMOVE should succeed with UPDATE permission +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Bob'}) + REMOVE p.hobby + RETURN p.name, p.hobby +$$) AS (name agtype, hobby agtype); + name | hobby +-------+------- + "Bob" | +(1 row) + +-- ============================================================================ +-- PART 6: DELETE Permission Tests +-- ============================================================================ +RESET ROLE; +SET ROLE security_test_readonly; +-- Test: DELETE should fail with only SELECT permission +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Charlie'}) + DELETE p +$$) AS (a agtype); +ERROR: permission denied for table Person +RESET ROLE; +SET ROLE security_test_update; +-- Test: DELETE should fail with only UPDATE permission (need DELETE) +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Charlie'}) + DELETE p +$$) AS (a agtype); +ERROR: permission denied for table Person +RESET ROLE; +SET ROLE security_test_delete; +-- Test: DELETE vertex should succeed with DELETE permission +-- First delete the edge connected to Charlie +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Charlie'})-[k:KNOWS]->() + DELETE k +$$) AS (a agtype); + a +--- +(0 rows) + +-- Now delete the vertex +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Charlie'}) + DELETE p +$$) AS (a agtype); + a +--- +(0 rows) + +-- Verify deletion +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Charlie'}) RETURN p +$$) AS (p agtype); + p +--- +(0 rows) + +-- ============================================================================ +-- PART 7: DETACH DELETE Tests +-- ============================================================================ +RESET ROLE; +-- Create a new vertex with edge for DETACH DELETE test +SELECT * FROM cypher('security_test', $$ + CREATE (:Person {name: 'Dave', age: 40}) +$$) AS (a agtype); + a +--- +(0 rows) + +SELECT * FROM cypher('security_test', $$ + MATCH (a:Person {name: 'Alice'}), (d:Person {name: 'Dave'}) + CREATE (a)-[:KNOWS {since: 2022}]->(d) +$$) AS (a agtype); + a +--- +(0 rows) + +SET ROLE security_test_detach_delete; +-- Test: DETACH DELETE should fail without DELETE on edge table +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Dave'}) + DETACH DELETE p +$$) AS (a agtype); +ERROR: permission denied for table KNOWS +RESET ROLE; +GRANT DELETE ON security_test."KNOWS" TO security_test_detach_delete; +SET ROLE security_test_detach_delete; +-- Test: DETACH DELETE should succeed now when user has DELETE on both vertex and edge tables +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Dave'}) + DETACH DELETE p +$$) AS (a agtype); + a +--- +(0 rows) + +-- Verify deletion +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Dave'}) RETURN p +$$) AS (p agtype); + p +--- +(0 rows) + +-- ============================================================================ +-- PART 8: MERGE Permission Tests +-- ============================================================================ +RESET ROLE; +SET ROLE security_test_readonly; +-- Test: MERGE that would create should fail without INSERT +SELECT * FROM cypher('security_test', $$ + MERGE (p:Person {name: 'Eve'}) + RETURN p +$$) AS (p agtype); +ERROR: permission denied for table Person +RESET ROLE; +SET ROLE security_test_insert; +-- Test: MERGE that creates should succeed with INSERT permission +SELECT * FROM cypher('security_test', $$ + MERGE (p:Person {name: 'Eve', age: 28}) + RETURN p.name, p.age +$$) AS (name agtype, age agtype); + name | age +-------+----- + "Eve" | 28 +(1 row) + +-- Test: MERGE that matches existing should succeed (only needs SELECT) +SELECT * FROM cypher('security_test', $$ + MERGE (p:Person {name: 'Eve'}) + RETURN p.name +$$) AS (name agtype); + name +------- + "Eve" +(1 row) + +-- ============================================================================ +-- PART 9: Full Permission Role Tests +-- ============================================================================ +RESET ROLE; +SET ROLE security_test_full; +-- Full permission role should be able to do everything +SELECT * FROM cypher('security_test', $$ + CREATE (:Person {name: 'Frank', age: 50}) +$$) AS (a agtype); + a +--- +(0 rows) + +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Frank'}) + SET p.age = 51 + RETURN p.name, p.age +$$) AS (name agtype, age agtype); + name | age +---------+----- + "Frank" | 51 +(1 row) + +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Frank'}) + DELETE p +$$) AS (a agtype); + a +--- +(0 rows) + +-- ============================================================================ +-- PART 10: Permission on Specific Labels +-- ============================================================================ +RESET ROLE; +-- Create a role with permission only on Person label, not Document +CREATE ROLE security_test_person_only LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_person_only; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_person_only; +GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA ag_catalog TO security_test_person_only; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_person_only; +-- Only grant permissions on Person table +GRANT SELECT, INSERT, UPDATE, DELETE ON security_test."Person" TO security_test_person_only; +GRANT SELECT ON security_test."KNOWS" TO security_test_person_only; +GRANT SELECT ON security_test._ag_label_vertex TO security_test_person_only; +GRANT SELECT ON security_test._ag_label_edge TO security_test_person_only; +GRANT USAGE ON ALL SEQUENCES IN SCHEMA security_test TO security_test_person_only; +SET ROLE security_test_person_only; +-- Test: Operations on Person should succeed +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Alice'}) RETURN p.name +$$) AS (name agtype); + name +--------- + "Alice" +(1 row) + +-- Test: SELECT on Document should fail (no permission) +SELECT * FROM cypher('security_test', $$ + MATCH (d:Document) RETURN d.title +$$) AS (title agtype); +ERROR: permission denied for table Document +-- Test: CREATE Document should fail (no permission on Document table) +SELECT * FROM cypher('security_test', $$ + CREATE (:Document {title: 'New Doc'}) +$$) AS (a agtype); +ERROR: permission denied for table Document +-- ============================================================================ +-- PART 11: Function EXECUTE Permission Tests +-- ============================================================================ +RESET ROLE; +-- Create role with no function execute permissions +CREATE ROLE security_test_noexec LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_noexec; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_noexec; +-- Revoke execute from PUBLIC on functions we want to test +REVOKE EXECUTE ON FUNCTION ag_catalog.create_graph(name) FROM PUBLIC; +REVOKE EXECUTE ON FUNCTION ag_catalog.drop_graph(name, boolean) FROM PUBLIC; +REVOKE EXECUTE ON FUNCTION ag_catalog.create_vlabel(cstring, cstring) FROM PUBLIC; +REVOKE EXECUTE ON FUNCTION ag_catalog.create_elabel(cstring, cstring) FROM PUBLIC; +SET ROLE security_test_noexec; +-- Test: create_graph should fail without EXECUTE permission +SELECT create_graph('unauthorized_graph'); +ERROR: permission denied for function create_graph +-- Test: drop_graph should fail without EXECUTE permission +SELECT drop_graph('security_test', true); +ERROR: permission denied for function drop_graph +-- Test: create_vlabel should fail without EXECUTE permission +SELECT create_vlabel('security_test', 'NewLabel'); +ERROR: permission denied for function create_vlabel +-- Test: create_elabel should fail without EXECUTE permission +SELECT create_elabel('security_test', 'NewEdge'); +ERROR: permission denied for function create_elabel +RESET ROLE; +-- Grant execute on specific function and test +GRANT EXECUTE ON FUNCTION ag_catalog.create_vlabel(cstring, cstring) TO security_test_noexec; +SET ROLE security_test_noexec; +-- Test: create_vlabel should now get past execute check (will fail on schema permission instead) +SELECT create_vlabel('security_test', 'TestLabel'); +ERROR: permission denied for schema security_test +-- Test: create_graph should still fail with execute permission denied +SELECT create_graph('unauthorized_graph'); +ERROR: permission denied for function create_graph +RESET ROLE; +-- Restore execute permissions to PUBLIC +GRANT EXECUTE ON FUNCTION ag_catalog.create_graph(name) TO PUBLIC; +GRANT EXECUTE ON FUNCTION ag_catalog.drop_graph(name, boolean) TO PUBLIC; +GRANT EXECUTE ON FUNCTION ag_catalog.create_vlabel(cstring, cstring) TO PUBLIC; +GRANT EXECUTE ON FUNCTION ag_catalog.create_elabel(cstring, cstring) TO PUBLIC; +-- ============================================================================ +-- PART 12: startNode/endNode Permission Tests +-- ============================================================================ +-- Create role with SELECT on base tables but NOT on Person label +CREATE ROLE security_test_edge_only LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_edge_only; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_edge_only; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_edge_only; +GRANT SELECT ON security_test."KNOWS" TO security_test_edge_only; +GRANT SELECT ON security_test._ag_label_edge TO security_test_edge_only; +GRANT SELECT ON security_test._ag_label_vertex TO security_test_edge_only; +-- Note: NOT granting SELECT on security_test."Person" +SET ROLE security_test_edge_only; +-- Test: endNode fails without SELECT on Person table +SELECT * FROM cypher('security_test', $$ + MATCH ()-[e:KNOWS]->() + RETURN endNode(e) +$$) AS (end_vertex agtype); +ERROR: permission denied for table Person +-- Test: startNode fails without SELECT on Person table +SELECT * FROM cypher('security_test', $$ + MATCH ()-[e:KNOWS]->() + RETURN startNode(e) +$$) AS (start_vertex agtype); +ERROR: permission denied for table Person +RESET ROLE; +-- Grant SELECT on Person and verify success +GRANT SELECT ON security_test."Person" TO security_test_edge_only; +SET ROLE security_test_edge_only; +-- Test: Should now succeed with SELECT permission +SELECT * FROM cypher('security_test', $$ + MATCH ()-[e:KNOWS]->() + RETURN startNode(e).name, endNode(e).name +$$) AS (start_name agtype, end_name agtype); + start_name | end_name +------------+---------- + "Alice" | "Bob" +(1 row) + +RESET ROLE; +-- ============================================================================ +-- Cleanup +-- ============================================================================ +RESET ROLE; +-- Drop all owned objects and privileges for each role, then drop the role +DROP OWNED BY security_test_noread CASCADE; +DROP ROLE security_test_noread; +DROP OWNED BY security_test_base_only CASCADE; +DROP ROLE security_test_base_only; +DROP OWNED BY security_test_readonly CASCADE; +DROP ROLE security_test_readonly; +DROP OWNED BY security_test_insert CASCADE; +DROP ROLE security_test_insert; +DROP OWNED BY security_test_update CASCADE; +DROP ROLE security_test_update; +DROP OWNED BY security_test_delete CASCADE; +DROP ROLE security_test_delete; +DROP OWNED BY security_test_detach_delete CASCADE; +DROP ROLE security_test_detach_delete; +DROP OWNED BY security_test_full CASCADE; +DROP ROLE security_test_full; +DROP OWNED BY security_test_person_only CASCADE; +DROP ROLE security_test_person_only; +DROP OWNED BY security_test_noexec CASCADE; +DROP ROLE security_test_noexec; +DROP OWNED BY security_test_edge_only CASCADE; +DROP ROLE security_test_edge_only; +-- Drop test graph +SELECT drop_graph('security_test', true); +NOTICE: drop cascades to 6 other objects +DETAIL: drop cascades to table security_test._ag_label_vertex +drop cascades to table security_test._ag_label_edge +drop cascades to table security_test."Person" +drop cascades to table security_test."Document" +drop cascades to table security_test."KNOWS" +drop cascades to table security_test."OWNS" +NOTICE: graph "security_test" has been dropped + drop_graph +------------ + +(1 row) + +-- +-- Row-Level Security (RLS) Tests +-- +-- +-- Setup: Create test graph, data and roles for RLS tests +-- +SELECT create_graph('rls_graph'); +NOTICE: graph "rls_graph" has been created + create_graph +-------------- + +(1 row) + +-- Create test roles +CREATE ROLE rls_user1 LOGIN; +CREATE ROLE rls_user2 LOGIN; +CREATE ROLE rls_admin LOGIN BYPASSRLS; -- Role that bypasses RLS +-- Create base test data FIRST (as superuser) - this creates the label tables +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'Alice', owner: 'rls_user1', department: 'Engineering', level: 1}) +$$) AS (a agtype); + a +--- +(0 rows) + +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'Bob', owner: 'rls_user2', department: 'Engineering', level: 2}) +$$) AS (a agtype); + a +--- +(0 rows) + +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'Charlie', owner: 'rls_user1', department: 'Sales', level: 1}) +$$) AS (a agtype); + a +--- +(0 rows) + +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'Diana', owner: 'rls_user2', department: 'Sales', level: 3}) +$$) AS (a agtype); + a +--- +(0 rows) + +-- Create a second vertex label for multi-label tests +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Document {title: 'Public Doc', classification: 'public', owner: 'rls_user1'}) +$$) AS (a agtype); + a +--- +(0 rows) + +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Document {title: 'Secret Doc', classification: 'secret', owner: 'rls_user2'}) +$$) AS (a agtype); + a +--- +(0 rows) + +-- Create edges +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Alice'}), (b:Person {name: 'Bob'}) + CREATE (a)-[:KNOWS {since: 2020, strength: 'weak'}]->(b) +$$) AS (a agtype); + a +--- +(0 rows) + +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Charlie'}), (b:Person {name: 'Diana'}) + CREATE (a)-[:KNOWS {since: 2021, strength: 'strong'}]->(b) +$$) AS (a agtype); + a +--- +(0 rows) + +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Alice'}), (b:Person {name: 'Charlie'}) + CREATE (a)-[:KNOWS {since: 2022, strength: 'strong'}]->(b) +$$) AS (a agtype); + a +--- +(0 rows) + +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Alice'}), (d:Document {title: 'Public Doc'}) + CREATE (a)-[:AUTHORED]->(d) +$$) AS (a agtype); + a +--- +(0 rows) + +-- Grant permissions AFTER creating tables (so Person, Document, KNOWS, AUTHORED exist) +GRANT USAGE ON SCHEMA rls_graph TO rls_user1, rls_user2, rls_admin; +GRANT ALL ON ALL TABLES IN SCHEMA rls_graph TO rls_user1, rls_user2, rls_admin; +GRANT USAGE ON SCHEMA ag_catalog TO rls_user1, rls_user2, rls_admin; +GRANT USAGE ON ALL SEQUENCES IN SCHEMA rls_graph TO rls_user1, rls_user2, rls_admin; +-- ============================================================================ +-- PART 1: Vertex SELECT Policies (USING clause) +-- ============================================================================ +-- Enable RLS on Person label +ALTER TABLE rls_graph."Person" ENABLE ROW LEVEL SECURITY; +ALTER TABLE rls_graph."Person" FORCE ROW LEVEL SECURITY; +-- 1.1: Basic ownership filtering +CREATE POLICY person_select_own ON rls_graph."Person" + FOR SELECT + USING (properties->>'"owner"' = current_user); +-- Test as rls_user1 - should only see Alice and Charlie (owned by rls_user1) +SET ROLE rls_user1; +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + name +----------- + "Alice" + "Charlie" +(2 rows) + +-- Test as rls_user2 - should only see Bob and Diana (owned by rls_user2) +SET ROLE rls_user2; +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + name +--------- + "Bob" + "Diana" +(2 rows) + +RESET ROLE; +-- 1.2: Default deny - no permissive policies means no access +DROP POLICY person_select_own ON rls_graph."Person"; +-- With no policies, RLS blocks all access +SET ROLE rls_user1; +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + name +------ +(0 rows) + +RESET ROLE; +-- ============================================================================ +-- PART 2: Vertex INSERT Policies (WITH CHECK) - CREATE +-- ============================================================================ +-- Allow SELECT for all (so we can verify results) +CREATE POLICY person_select_all ON rls_graph."Person" + FOR SELECT USING (true); +-- 2.1: Basic WITH CHECK - users can only insert rows they own +CREATE POLICY person_insert_own ON rls_graph."Person" + FOR INSERT + WITH CHECK (properties->>'"owner"' = current_user); +-- Test as rls_user1 - should succeed (owner matches current_user) +SET ROLE rls_user1; +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'User1Created', owner: 'rls_user1', department: 'Test', level: 1}) +$$) AS (a agtype); + a +--- +(0 rows) + +-- Test as rls_user1 - should FAIL (owner doesn't match current_user) +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'User1Fake', owner: 'rls_user2', department: 'Test', level: 1}) +$$) AS (a agtype); +ERROR: new row violates row-level security policy for table "Person" +RESET ROLE; +-- Verify only User1Created was created +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department = 'Test' RETURN p.name ORDER BY p.name +$$) AS (name agtype); + name +---------------- + "User1Created" +(1 row) + +-- 2.2: Default deny for INSERT - no INSERT policy blocks all inserts +DROP POLICY person_insert_own ON rls_graph."Person"; +SET ROLE rls_user1; +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'ShouldFail', owner: 'rls_user1', department: 'Blocked', level: 1}) +$$) AS (a agtype); +ERROR: new row violates row-level security policy for table "Person" +RESET ROLE; +-- Verify nothing was created in Blocked department +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department = 'Blocked' RETURN p.name +$$) AS (name agtype); + name +------ +(0 rows) + +-- cleanup +DROP POLICY person_select_all ON rls_graph."Person"; +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department = 'Test' DELETE p +$$) AS (a agtype); + a +--- +(0 rows) + +-- ============================================================================ +-- PART 3: Vertex UPDATE Policies - SET +-- ============================================================================ +CREATE POLICY person_select_all ON rls_graph."Person" + FOR SELECT USING (true); +-- 3.1: USING clause only - filter which rows can be updated +CREATE POLICY person_update_using ON rls_graph."Person" + FOR UPDATE + USING (properties->>'"owner"' = current_user); +SET ROLE rls_user1; +-- Should succeed - rls_user1 owns Alice +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Alice'}) SET p.updated = true RETURN p.name, p.updated +$$) AS (name agtype, updated agtype); + name | updated +---------+--------- + "Alice" | true +(1 row) + +-- Should silently skip - rls_user1 doesn't own Bob (USING filters it out) +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Bob'}) SET p.updated = true RETURN p.name, p.updated +$$) AS (name agtype, updated agtype); + name | updated +------+--------- +(0 rows) + +RESET ROLE; +-- Verify Alice was updated, Bob was not +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.name IN ['Alice', 'Bob'] RETURN p.name, p.updated ORDER BY p.name +$$) AS (name agtype, updated agtype); + name | updated +---------+--------- + "Alice" | true + "Bob" | +(2 rows) + +-- 3.2: WITH CHECK clause - validate new values +DROP POLICY person_update_using ON rls_graph."Person"; +CREATE POLICY person_update_check ON rls_graph."Person" + FOR UPDATE + USING (true) -- Can update any row + WITH CHECK (properties->>'"owner"' = current_user); -- But new value must keep owner +SET ROLE rls_user1; +-- Should succeed - modifying property but keeping owner +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Alice'}) SET p.verified = true RETURN p.name, p.verified +$$) AS (name agtype, verified agtype); + name | verified +---------+---------- + "Alice" | true +(1 row) + +-- Should FAIL - trying to change owner to someone else +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Alice'}) SET p.owner = 'rls_user2' RETURN p.owner +$$) AS (owner agtype); +ERROR: new row violates row-level security policy for table "Person" +RESET ROLE; +-- Verify owner wasn't changed +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Alice'}) RETURN p.owner +$$) AS (owner agtype); + owner +------------- + "rls_user1" +(1 row) + +-- 3.3: Both USING and WITH CHECK together +DROP POLICY person_update_check ON rls_graph."Person"; +CREATE POLICY person_update_both ON rls_graph."Person" + FOR UPDATE + USING (properties->>'"owner"' = current_user) + WITH CHECK (properties->>'"owner"' = current_user); +SET ROLE rls_user1; +-- Should succeed - owns Alice, keeping owner +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Alice'}) SET p.status = 'active' RETURN p.name, p.status +$$) AS (name agtype, status agtype); + name | status +---------+---------- + "Alice" | "active" +(1 row) + +-- Should silently skip - doesn't own Bob (USING filters) +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Bob'}) SET p.status = 'active' RETURN p.name, p.status +$$) AS (name agtype, status agtype); + name | status +------+-------- +(0 rows) + +RESET ROLE; +-- ============================================================================ +-- PART 4: Vertex UPDATE Policies - REMOVE +-- ============================================================================ +-- Keep existing update policy, test REMOVE operation +SET ROLE rls_user1; +-- Should succeed - owns Alice +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Alice'}) REMOVE p.status RETURN p.name, p.status +$$) AS (name agtype, status agtype); + name | status +---------+-------- + "Alice" | +(1 row) + +-- Should silently skip - doesn't own Bob +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Bob'}) REMOVE p.department RETURN p.name, p.department +$$) AS (name agtype, dept agtype); + name | dept +------+------ +(0 rows) + +RESET ROLE; +-- Verify Bob still has department +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Bob'}) RETURN p.department +$$) AS (dept agtype); + dept +--------------- + "Engineering" +(1 row) + +-- cleanup +DROP POLICY person_select_all ON rls_graph."Person"; +DROP POLICY person_update_both ON rls_graph."Person"; +-- ============================================================================ +-- PART 5: Vertex DELETE Policies +-- ============================================================================ +CREATE POLICY person_select_all ON rls_graph."Person" + FOR SELECT USING (true); +-- Create test data for delete tests +CREATE POLICY person_insert_all ON rls_graph."Person" + FOR INSERT WITH CHECK (true); +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'DeleteTest1', owner: 'rls_user1', department: 'DeleteTest', level: 1}) +$$) AS (a agtype); + a +--- +(0 rows) + +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'DeleteTest2', owner: 'rls_user2', department: 'DeleteTest', level: 1}) +$$) AS (a agtype); + a +--- +(0 rows) + +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'DeleteTest3', owner: 'rls_user1', department: 'DeleteTest', level: 1}) +$$) AS (a agtype); + a +--- +(0 rows) + +DROP POLICY person_insert_all ON rls_graph."Person"; +-- 5.1: Basic USING filtering for DELETE +CREATE POLICY person_delete_own ON rls_graph."Person" + FOR DELETE + USING (properties->>'"owner"' = current_user); +SET ROLE rls_user1; +-- Should succeed - owns DeleteTest1 +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'DeleteTest1'}) DELETE p +$$) AS (a agtype); + a +--- +(0 rows) + +-- Should silently skip - doesn't own DeleteTest2 +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'DeleteTest2'}) DELETE p +$$) AS (a agtype); + a +--- +(0 rows) + +RESET ROLE; +-- Verify DeleteTest1 deleted, DeleteTest2 still exists +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department = 'DeleteTest' RETURN p.name ORDER BY p.name +$$) AS (name agtype); + name +--------------- + "DeleteTest2" + "DeleteTest3" +(2 rows) + +-- 5.2: Default deny for DELETE - no policy blocks all deletes +DROP POLICY person_delete_own ON rls_graph."Person"; +SET ROLE rls_user1; +-- Should silently skip - no DELETE policy means default deny +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'DeleteTest3'}) DELETE p +$$) AS (a agtype); + a +--- +(0 rows) + +RESET ROLE; +-- Verify DeleteTest3 still exists +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'DeleteTest3'}) RETURN p.name +$$) AS (name agtype); + name +--------------- + "DeleteTest3" +(1 row) + +-- cleanup +DROP POLICY person_select_all ON rls_graph."Person"; +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department = 'DeleteTest' DELETE p +$$) AS (a agtype); + a +--- +(0 rows) + +-- ============================================================================ +-- PART 6: MERGE Policies +-- ============================================================================ +CREATE POLICY person_select_all ON rls_graph."Person" + FOR SELECT USING (true); +CREATE POLICY person_insert_own ON rls_graph."Person" + FOR INSERT + WITH CHECK (properties->>'"owner"' = current_user); +-- 6.1: MERGE creating new vertex - INSERT policy applies +SET ROLE rls_user1; +-- Should succeed - creating with correct owner +SELECT * FROM cypher('rls_graph', $$ + MERGE (p:Person {name: 'MergeNew1', owner: 'rls_user1', department: 'Merge', level: 1}) + RETURN p.name +$$) AS (name agtype); + name +------------- + "MergeNew1" +(1 row) + +-- Should FAIL - creating with wrong owner +SELECT * FROM cypher('rls_graph', $$ + MERGE (p:Person {name: 'MergeNew2', owner: 'rls_user2', department: 'Merge', level: 1}) + RETURN p.name +$$) AS (name agtype); +ERROR: new row violates row-level security policy for table "Person" +RESET ROLE; +-- 6.2: MERGE matching existing - only SELECT needed +SET ROLE rls_user1; +-- Should succeed - Alice exists and SELECT allowed +SELECT * FROM cypher('rls_graph', $$ + MERGE (p:Person {name: 'Alice'}) + RETURN p.name, p.owner +$$) AS (name agtype, owner agtype); + name | owner +---------+------------- + "Alice" | "rls_user1" +(1 row) + +RESET ROLE; +-- Verify only MergeNew1 was created +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department = 'Merge' RETURN p.name ORDER BY p.name +$$) AS (name agtype); + name +------------- + "MergeNew1" +(1 row) + +-- cleanup +DROP POLICY person_select_all ON rls_graph."Person"; +DROP POLICY person_insert_own ON rls_graph."Person"; +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department = 'Merge' DELETE p +$$) AS (a agtype); + a +--- +(0 rows) + +-- ============================================================================ +-- PART 7: Edge SELECT Policies +-- ============================================================================ +-- Disable vertex RLS, enable edge RLS +ALTER TABLE rls_graph."Person" DISABLE ROW LEVEL SECURITY; +ALTER TABLE rls_graph."KNOWS" ENABLE ROW LEVEL SECURITY; +ALTER TABLE rls_graph."KNOWS" FORCE ROW LEVEL SECURITY; +-- Policy: Only see edges from 2021 or later +CREATE POLICY knows_select_recent ON rls_graph."KNOWS" + FOR SELECT + USING ((properties->>'"since"')::int >= 2021); +SET ROLE rls_user1; +-- Should only see 2021 and 2022 edges (not 2020) +SELECT * FROM cypher('rls_graph', $$ + MATCH ()-[k:KNOWS]->() RETURN k.since ORDER BY k.since +$$) AS (since agtype); + since +------- + 2021 + 2022 +(2 rows) + +RESET ROLE; +-- ============================================================================ +-- PART 8: Edge INSERT Policies (CREATE edge) +-- ============================================================================ +DROP POLICY knows_select_recent ON rls_graph."KNOWS"; +CREATE POLICY knows_select_all ON rls_graph."KNOWS" + FOR SELECT USING (true); +-- Policy: Can only create edges with strength = 'strong' +CREATE POLICY knows_insert_strong ON rls_graph."KNOWS" + FOR INSERT + WITH CHECK (properties->>'"strength"' = 'strong'); +SET ROLE rls_user1; +-- Should succeed - strength is 'strong' +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Bob'}), (b:Person {name: 'Diana'}) + CREATE (a)-[:KNOWS {since: 2023, strength: 'strong'}]->(b) +$$) AS (a agtype); + a +--- +(0 rows) + +-- Should FAIL - strength is 'weak' +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Diana'}), (b:Person {name: 'Alice'}) + CREATE (a)-[:KNOWS {since: 2023, strength: 'weak'}]->(b) +$$) AS (a agtype); +ERROR: new row violates row-level security policy for table "KNOWS" +RESET ROLE; +-- Verify only strong edge was created +SELECT * FROM cypher('rls_graph', $$ + MATCH ()-[k:KNOWS]->() WHERE k.since = 2023 RETURN k.strength ORDER BY k.strength +$$) AS (strength agtype); + strength +---------- + "strong" +(1 row) + +-- cleanup +DROP POLICY knows_insert_strong ON rls_graph."KNOWS"; +-- ============================================================================ +-- PART 9: Edge UPDATE Policies (SET on edge) +-- ============================================================================ +-- Policy: Can only update edges with strength = 'strong' +CREATE POLICY knows_update_strong ON rls_graph."KNOWS" + FOR UPDATE + USING (properties->>'"strength"' = 'strong') + WITH CHECK (properties->>'"strength"' = 'strong'); +SET ROLE rls_user1; +-- Should succeed - edge has strength 'strong' +SELECT * FROM cypher('rls_graph', $$ + MATCH ()-[k:KNOWS {since: 2021}]->() SET k.notes = 'updated' RETURN k.since, k.notes +$$) AS (since agtype, notes agtype); + since | notes +-------+----------- + 2021 | "updated" +(1 row) + +-- Should silently skip - edge has strength 'weak' +SELECT * FROM cypher('rls_graph', $$ + MATCH ()-[k:KNOWS {since: 2020}]->() SET k.notes = 'updated' RETURN k.since, k.notes +$$) AS (since agtype, notes agtype); + since | notes +-------+------- +(0 rows) + +RESET ROLE; +-- Verify only 2021 edge was updated +SELECT * FROM cypher('rls_graph', $$ + MATCH ()-[k:KNOWS]->() WHERE k.since IN [2020, 2021] RETURN k.since, k.notes ORDER BY k.since +$$) AS (since agtype, notes agtype); + since | notes +-------+----------- + 2020 | + 2021 | "updated" +(2 rows) + +-- cleanup +DROP POLICY knows_select_all ON rls_graph."KNOWS"; +DROP POLICY knows_update_strong ON rls_graph."KNOWS"; +-- ============================================================================ +-- PART 10: Edge DELETE Policies +-- ============================================================================ +CREATE POLICY knows_select_all ON rls_graph."KNOWS" + FOR SELECT USING (true); +-- Create test edges for delete +CREATE POLICY knows_insert_all ON rls_graph."KNOWS" + FOR INSERT WITH CHECK (true); +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Bob'}), (b:Person {name: 'Charlie'}) + CREATE (a)-[:KNOWS {since: 2018, strength: 'weak'}]->(b) +$$) AS (a agtype); + a +--- +(0 rows) + +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Diana'}), (b:Person {name: 'Charlie'}) + CREATE (a)-[:KNOWS {since: 2019, strength: 'strong'}]->(b) +$$) AS (a agtype); + a +--- +(0 rows) + +DROP POLICY knows_insert_all ON rls_graph."KNOWS"; +-- Policy: Can only delete edges with strength = 'weak' +CREATE POLICY knows_delete_weak ON rls_graph."KNOWS" + FOR DELETE + USING (properties->>'"strength"' = 'weak'); +SET ROLE rls_user1; +-- Should succeed - edge has strength 'weak' +SELECT * FROM cypher('rls_graph', $$ + MATCH ()-[k:KNOWS {since: 2018}]->() DELETE k +$$) AS (a agtype); + a +--- +(0 rows) + +-- Should silently skip - edge has strength 'strong' +SELECT * FROM cypher('rls_graph', $$ + MATCH ()-[k:KNOWS {since: 2019}]->() DELETE k +$$) AS (a agtype); + a +--- +(0 rows) + +RESET ROLE; +-- Verify 2018 edge deleted, 2019 edge still exists +SELECT * FROM cypher('rls_graph', $$ + MATCH ()-[k:KNOWS]->() WHERE k.since IN [2018, 2019] RETURN k.since ORDER BY k.since +$$) AS (since agtype); + since +------- + 2019 +(1 row) + +-- cleanup +DROP POLICY knows_delete_weak ON rls_graph."KNOWS"; +-- ============================================================================ +-- PART 11: DETACH DELETE +-- ============================================================================ +-- Re-enable Person RLS +ALTER TABLE rls_graph."Person" ENABLE ROW LEVEL SECURITY; +CREATE POLICY person_all ON rls_graph."Person" + FOR ALL USING (true) WITH CHECK (true); +-- Create test data with a protected edge +CREATE POLICY knows_insert_all ON rls_graph."KNOWS" + FOR INSERT WITH CHECK (true); +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'DetachTest1', owner: 'test', department: 'Detach', level: 1}) +$$) AS (a agtype); + a +--- +(0 rows) + +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'DetachTest2', owner: 'test', department: 'Detach', level: 1}) +$$) AS (a agtype); + a +--- +(0 rows) + +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'DetachTest1'}), (b:Person {name: 'DetachTest2'}) + CREATE (a)-[:KNOWS {since: 2010, strength: 'protected'}]->(b) +$$) AS (a agtype); + a +--- +(0 rows) + +DROP POLICY knows_insert_all ON rls_graph."KNOWS"; +-- Policy: Cannot delete edges with strength = 'protected' +CREATE POLICY knows_delete_not_protected ON rls_graph."KNOWS" + FOR DELETE + USING (properties->>'"strength"' != 'protected'); +SET ROLE rls_user1; +-- Should ERROR - DETACH DELETE cannot silently skip (would leave dangling edge) +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'DetachTest1'}) DETACH DELETE p +$$) AS (a agtype); +ERROR: cannot delete edge due to row-level security policy on "KNOWS" +HINT: DETACH DELETE requires permission to delete all connected edges. +RESET ROLE; +-- Verify vertex still exists (delete was blocked) +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'DetachTest1'}) RETURN p.name +$$) AS (name agtype); + name +--------------- + "DetachTest1" +(1 row) + +-- cleanup +DROP POLICY person_all ON rls_graph."Person"; +DROP POLICY knows_select_all ON rls_graph."KNOWS"; +DROP POLICY knows_delete_not_protected ON rls_graph."KNOWS"; +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department = 'Detach' DETACH DELETE p +$$) AS (a agtype); + a +--- +(0 rows) + +-- ============================================================================ +-- PART 12: Multiple Labels in Single Query +-- ============================================================================ +-- Enable RLS on Document too +ALTER TABLE rls_graph."Document" ENABLE ROW LEVEL SECURITY; +ALTER TABLE rls_graph."Document" FORCE ROW LEVEL SECURITY; +-- Policy: Users see their own Person records +CREATE POLICY person_own ON rls_graph."Person" + FOR SELECT + USING (properties->>'"owner"' = current_user); +-- Policy: Users see only public documents +CREATE POLICY doc_public ON rls_graph."Document" + FOR SELECT + USING (properties->>'"classification"' = 'public'); +SET ROLE rls_user1; +-- Should only see Alice and Charlie (Person) with Public Doc (Document) +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + name +----------- + "Alice" + "Charlie" +(2 rows) + +SELECT * FROM cypher('rls_graph', $$ + MATCH (d:Document) RETURN d.title ORDER BY d.title +$$) AS (title agtype); + title +-------------- + "Public Doc" +(1 row) + +-- Combined query - should respect both policies +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person)-[:AUTHORED]->(d:Document) + RETURN p.name, d.title +$$) AS (person agtype, doc agtype); + person | doc +---------+-------------- + "Alice" | "Public Doc" +(1 row) + +RESET ROLE; +-- ============================================================================ +-- PART 13: Permissive vs Restrictive Policies +-- ============================================================================ +DROP POLICY person_own ON rls_graph."Person"; +DROP POLICY doc_public ON rls_graph."Document"; +ALTER TABLE rls_graph."Document" DISABLE ROW LEVEL SECURITY; +ALTER TABLE rls_graph."KNOWS" DISABLE ROW LEVEL SECURITY; +-- 13.1: Multiple permissive policies (OR logic) +CREATE POLICY person_permissive_own ON rls_graph."Person" + AS PERMISSIVE FOR SELECT + USING (properties->>'"owner"' = current_user); +CREATE POLICY person_permissive_eng ON rls_graph."Person" + AS PERMISSIVE FOR SELECT + USING (properties->>'"department"' = 'Engineering'); +SET ROLE rls_user1; +-- Should see: Alice (own), Charlie (own), Bob (Engineering) +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department IN ['Engineering', 'Sales'] + RETURN p.name ORDER BY p.name +$$) AS (name agtype); + name +----------- + "Alice" + "Bob" + "Charlie" +(3 rows) + +RESET ROLE; +-- 13.2: Add restrictive policy (AND with permissive) +CREATE POLICY person_restrictive_level ON rls_graph."Person" + AS RESTRICTIVE FOR SELECT + USING ((properties->>'"level"')::int <= 2); +SET ROLE rls_user1; +-- Should see: Alice (own, level 1), Bob (Engineering, level 2), Charlie (own, level 1) +-- Diana (level 3) blocked by restrictive +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name, p.level ORDER BY p.name +$$) AS (name agtype, level agtype); + name | level +-----------+------- + "Alice" | 1 + "Bob" | 2 + "Charlie" | 1 +(3 rows) + +RESET ROLE; +-- 13.3: Multiple restrictive policies (all must pass) +CREATE POLICY person_restrictive_sales ON rls_graph."Person" + AS RESTRICTIVE FOR SELECT + USING (properties->>'"department"' != 'Sales'); +SET ROLE rls_user1; +-- Should see: Alice (own, level 1, not Sales), Bob (Engineering, level 2, not Sales) +-- Charlie blocked by Sales restriction +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + name +--------- + "Alice" + "Bob" +(2 rows) + +RESET ROLE; +-- ============================================================================ +-- PART 14: BYPASSRLS Role and Superuser Behavior +-- ============================================================================ +DROP POLICY person_permissive_own ON rls_graph."Person"; +DROP POLICY person_permissive_eng ON rls_graph."Person"; +DROP POLICY person_restrictive_level ON rls_graph."Person"; +DROP POLICY person_restrictive_sales ON rls_graph."Person"; +-- Restrictive policy that blocks most access +CREATE POLICY person_very_restrictive ON rls_graph."Person" + FOR SELECT + USING (properties->>'"name"' = 'Nobody'); +-- 14.1: Regular user sees nothing +SET ROLE rls_user1; +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + name +------ +(0 rows) + +RESET ROLE; +-- 14.2: BYPASSRLS role sees everything +SET ROLE rls_admin; +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + name +----------- + "Alice" + "Bob" + "Charlie" + "Diana" +(4 rows) + +RESET ROLE; +-- 14.3: Superuser sees everything (implicit bypass) +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + name +----------- + "Alice" + "Bob" + "Charlie" + "Diana" +(4 rows) + +-- ============================================================================ +-- PART 15: Complex Multi-Operation Queries +-- ============================================================================ +DROP POLICY person_very_restrictive ON rls_graph."Person"; +CREATE POLICY person_select_all ON rls_graph."Person" + FOR SELECT USING (true); +CREATE POLICY person_insert_own ON rls_graph."Person" + FOR INSERT + WITH CHECK (properties->>'"owner"' = current_user); +CREATE POLICY person_update_own ON rls_graph."Person" + FOR UPDATE + USING (properties->>'"owner"' = current_user) + WITH CHECK (properties->>'"owner"' = current_user); +-- 15.1: MATCH + CREATE in one query +SET ROLE rls_user1; +-- Should succeed - creating with correct owner +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Alice'}) + CREATE (a)-[:KNOWS]->(:Person {name: 'NewFromMatch', owner: 'rls_user1', department: 'Complex', level: 1}) +$$) AS (a agtype); + a +--- +(0 rows) + +RESET ROLE; +-- Verify creation +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'NewFromMatch'}) RETURN p.name, p.owner +$$) AS (name agtype, owner agtype); + name | owner +----------------+------------- + "NewFromMatch" | "rls_user1" +(1 row) + +-- 15.2: MATCH + SET in one query +SET ROLE rls_user1; +-- Should succeed on Alice (own), skip Bob (not own) +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.name IN ['Alice', 'Bob'] + SET p.complexTest = true + RETURN p.name, p.complexTest +$$) AS (name agtype, test agtype); + name | test +---------+------ + "Alice" | true +(1 row) + +RESET ROLE; +-- Verify only Alice was updated +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.name IN ['Alice', 'Bob'] + RETURN p.name, p.complexTest ORDER BY p.name +$$) AS (name agtype, test agtype); + name | test +---------+------ + "Alice" | true + "Bob" | +(2 rows) + +-- cleanup +DROP POLICY IF EXISTS person_select_all ON rls_graph."Person"; +DROP POLICY IF EXISTS person_insert_own ON rls_graph."Person"; +DROP POLICY IF EXISTS person_update_own ON rls_graph."Person"; +-- ============================================================================ +-- PART 16: startNode/endNode RLS Enforcement +-- ============================================================================ +ALTER TABLE rls_graph."Person" DISABLE ROW LEVEL SECURITY; +-- Enable RLS on Person with restrictive policy +ALTER TABLE rls_graph."Person" ENABLE ROW LEVEL SECURITY; +ALTER TABLE rls_graph."Person" FORCE ROW LEVEL SECURITY; +-- Policy: users can only see their own Person records +CREATE POLICY person_own ON rls_graph."Person" + FOR SELECT + USING (properties->>'"owner"' = current_user); +-- Enable edge access for testing +ALTER TABLE rls_graph."KNOWS" ENABLE ROW LEVEL SECURITY; +CREATE POLICY knows_all ON rls_graph."KNOWS" + FOR SELECT USING (true); +-- 16.1: startNode blocked by RLS - should error +SET ROLE rls_user1; +-- rls_user1 can see the edge (Alice->Bob) but cannot see Bob (owned by rls_user2) +-- endNode should error because Bob is blocked by RLS +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Alice'})-[e:KNOWS]->(b) + RETURN endNode(e) +$$) AS (end_vertex agtype); +ERROR: access to vertex 844424930131970 denied by row-level security policy on "Person" +-- 16.2: endNode blocked by RLS - should error +-- rls_user1 cannot see Bob, so startNode on an edge starting from Bob should error +SET ROLE rls_user2; +-- rls_user2 can see Bob but not Alice (owned by rls_user1) +-- startNode should error because Alice is blocked by RLS +SELECT * FROM cypher('rls_graph', $$ + MATCH (a)-[e:KNOWS]->(b:Person {name: 'Bob'}) + RETURN startNode(e) +$$) AS (start_vertex agtype); +ERROR: access to vertex 844424930131969 denied by row-level security policy on "Person" +-- 16.3: startNode/endNode succeed when RLS allows access +SET ROLE rls_user1; +-- Alice->Charlie edge: rls_user1 owns both, should succeed +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Alice'})-[e:KNOWS]->(c:Person {name: 'Charlie'}) + RETURN startNode(e).name, endNode(e).name +$$) AS (start_name agtype, end_name agtype); + start_name | end_name +------------+----------- + "Alice" | "Charlie" +(1 row) + +RESET ROLE; +-- cleanup +DROP POLICY person_own ON rls_graph."Person"; +DROP POLICY knows_all ON rls_graph."KNOWS"; +ALTER TABLE rls_graph."KNOWS" DISABLE ROW LEVEL SECURITY; +-- ============================================================================ +-- RLS CLEANUP +-- ============================================================================ +RESET ROLE; +-- Disable RLS on all tables +ALTER TABLE rls_graph."Person" DISABLE ROW LEVEL SECURITY; +ALTER TABLE rls_graph."Document" DISABLE ROW LEVEL SECURITY; +ALTER TABLE rls_graph."KNOWS" DISABLE ROW LEVEL SECURITY; +-- Drop roles +DROP OWNED BY rls_user1 CASCADE; +DROP ROLE rls_user1; +DROP OWNED BY rls_user2 CASCADE; +DROP ROLE rls_user2; +DROP OWNED BY rls_admin CASCADE; +DROP ROLE rls_admin; +-- Drop test graph +SELECT drop_graph('rls_graph', true); +NOTICE: drop cascades to 6 other objects +DETAIL: drop cascades to table rls_graph._ag_label_vertex +drop cascades to table rls_graph._ag_label_edge +drop cascades to table rls_graph."Person" +drop cascades to table rls_graph."Document" +drop cascades to table rls_graph."KNOWS" +drop cascades to table rls_graph."AUTHORED" +NOTICE: graph "rls_graph" has been dropped + drop_graph +------------ + +(1 row) + diff --git a/regress/sql/security.sql b/regress/sql/security.sql new file mode 100644 index 000000000..344dd23d4 --- /dev/null +++ b/regress/sql/security.sql @@ -0,0 +1,1451 @@ +/* + * Licensed to the Apache Software Foundation (ASF) under one + * or more contributor license agreements. See the NOTICE file + * distributed with this work for additional information + * regarding copyright ownership. The ASF licenses this file + * to you under the Apache License, Version 2.0 (the + * "License"); you may not use this file except in compliance + * with the License. You may obtain a copy of the License at + * + * http://www.apache.org/licenses/LICENSE-2.0 + * + * Unless required by applicable law or agreed to in writing, + * software distributed under the License is distributed on an + * "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY + * KIND, either express or implied. See the License for the + * specific language governing permissions and limitations + * under the License. + */ + +LOAD 'age'; +SET search_path TO ag_catalog; + +-- +-- Test Privileges +-- + +-- +-- Setup: Create test graph and data as superuser +-- +SELECT create_graph('security_test'); + +-- Create test vertices +SELECT * FROM cypher('security_test', $$ + CREATE (:Person {name: 'Alice', age: 30}) +$$) AS (a agtype); + +SELECT * FROM cypher('security_test', $$ + CREATE (:Person {name: 'Bob', age: 25}) +$$) AS (a agtype); + +SELECT * FROM cypher('security_test', $$ + CREATE (:Document {title: 'Secret', content: 'classified'}) +$$) AS (a agtype); + +-- Create test edges +SELECT * FROM cypher('security_test', $$ + MATCH (a:Person {name: 'Alice'}), (b:Person {name: 'Bob'}) + CREATE (a)-[:KNOWS {since: 2020}]->(b) +$$) AS (a agtype); + +SELECT * FROM cypher('security_test', $$ + MATCH (a:Person {name: 'Alice'}), (d:Document) + CREATE (a)-[:OWNS]->(d) +$$) AS (a agtype); + +-- +-- Create test roles with different permission levels +-- + +-- Role with only SELECT (read-only) +CREATE ROLE security_test_readonly LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_readonly; +GRANT SELECT ON ALL TABLES IN SCHEMA security_test TO security_test_readonly; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_readonly; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_readonly; + +-- Role with SELECT and INSERT +CREATE ROLE security_test_insert LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_insert; +GRANT SELECT, INSERT ON ALL TABLES IN SCHEMA security_test TO security_test_insert; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_insert; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_insert; +-- Grant sequence usage for ID generation +GRANT USAGE ON ALL SEQUENCES IN SCHEMA security_test TO security_test_insert; + +-- Role with SELECT and UPDATE +CREATE ROLE security_test_update LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_update; +GRANT SELECT, UPDATE ON ALL TABLES IN SCHEMA security_test TO security_test_update; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_update; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_update; + +-- Role with SELECT and DELETE +CREATE ROLE security_test_delete LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_delete; +GRANT SELECT, DELETE ON ALL TABLES IN SCHEMA security_test TO security_test_delete; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_delete; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_delete; + +CREATE ROLE security_test_detach_delete LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_detach_delete; +GRANT SELECT ON ALL TABLES IN SCHEMA security_test TO security_test_detach_delete; +GRANT DELETE ON security_test."Person" TO security_test_detach_delete; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_detach_delete; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_detach_delete; + +-- Role with all permissions +CREATE ROLE security_test_full LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_full; +GRANT ALL ON ALL TABLES IN SCHEMA security_test TO security_test_full; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_full; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_full; +GRANT USAGE ON ALL SEQUENCES IN SCHEMA security_test TO security_test_full; + +-- Role with NO SELECT on graph tables (to test read failures) +CREATE ROLE security_test_noread LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_noread; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_noread; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_noread; +-- No SELECT on security_test tables + +-- ============================================================================ +-- PART 1: SELECT Permission Tests - Failure Cases (No Read Permission) +-- ============================================================================ + +SET ROLE security_test_noread; + +-- Test: MATCH on vertices should fail without SELECT permission +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person) RETURN p.name +$$) AS (name agtype); + +-- Test: MATCH on edges should fail without SELECT permission +SELECT * FROM cypher('security_test', $$ + MATCH ()-[k:KNOWS]->() RETURN k +$$) AS (k agtype); + +-- Test: MATCH with path should fail +SELECT * FROM cypher('security_test', $$ + MATCH (a)-[e]->(b) RETURN a, e, b +$$) AS (a agtype, e agtype, b agtype); + +RESET ROLE; + +-- Create role with SELECT only on base label tables, not child labels +-- NOTE: PostgreSQL inheritance allows access to child table rows when querying +-- through a parent table. This is expected behavior - SELECT on _ag_label_vertex +-- allows reading all vertices (including Person, Document) via inheritance. +CREATE ROLE security_test_base_only LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_base_only; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_base_only; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_base_only; +-- Only grant SELECT on base tables, NOT on Person, Document, KNOWS, OWNS +GRANT SELECT ON security_test._ag_label_vertex TO security_test_base_only; +GRANT SELECT ON security_test._ag_label_edge TO security_test_base_only; + +SET ROLE security_test_base_only; + +-- Test: MATCH (n) succeeds because PostgreSQL inheritance allows access to child rows +-- when querying through parent table. Permission on _ag_label_vertex grants read +-- access to all vertices via inheritance hierarchy. +SELECT * FROM cypher('security_test', $$ + MATCH (n) RETURN n +$$) AS (n agtype); + +-- Test: MATCH ()-[e]->() succeeds via inheritance (same reason as above) +SELECT * FROM cypher('security_test', $$ + MATCH ()-[e]->() RETURN e +$$) AS (e agtype); + +-- ============================================================================ +-- PART 2: SELECT Permission Tests - Success Cases (Read-Only Role) +-- ============================================================================ + +RESET ROLE; +SET ROLE security_test_readonly; + +-- Test: MATCH should succeed with SELECT permission +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + +-- Test: MATCH with edges should succeed +SELECT * FROM cypher('security_test', $$ + MATCH (a:Person)-[k:KNOWS]->(b:Person) + RETURN a.name, b.name +$$) AS (a agtype, b agtype); + +-- Test: MATCH across multiple labels should succeed +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person)-[:OWNS]->(d:Document) + RETURN p.name, d.title +$$) AS (person agtype, doc agtype); + +-- ============================================================================ +-- PART 3: INSERT Permission Tests (CREATE clause) +-- ============================================================================ + +-- Test: CREATE should fail with only SELECT permission +SELECT * FROM cypher('security_test', $$ + CREATE (:Person {name: 'Charlie'}) +$$) AS (a agtype); + +-- Test: CREATE edge should fail +SELECT * FROM cypher('security_test', $$ + MATCH (a:Person {name: 'Alice'}), (b:Person {name: 'Bob'}) + CREATE (a)-[:FRIENDS]->(b) +$$) AS (a agtype); + +RESET ROLE; +SET ROLE security_test_insert; + +-- Test: CREATE vertex should succeed with INSERT permission +SELECT * FROM cypher('security_test', $$ + CREATE (:Person {name: 'Charlie', age: 35}) +$$) AS (a agtype); + +-- Test: CREATE edge should succeed with INSERT permission +SELECT * FROM cypher('security_test', $$ + MATCH (a:Person {name: 'Charlie'}), (b:Person {name: 'Alice'}) + CREATE (a)-[:KNOWS {since: 2023}]->(b) +$$) AS (a agtype); + +-- Verify the inserts worked +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Charlie'}) RETURN p.name, p.age +$$) AS (name agtype, age agtype); + +-- ============================================================================ +-- PART 4: UPDATE Permission Tests (SET clause) +-- ============================================================================ + +RESET ROLE; +SET ROLE security_test_readonly; + +-- Test: SET should fail with only SELECT permission +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Alice'}) + SET p.age = 31 + RETURN p +$$) AS (p agtype); + +-- Test: SET on edge should fail +SELECT * FROM cypher('security_test', $$ + MATCH ()-[k:KNOWS]->() + SET k.since = 2021 + RETURN k +$$) AS (k agtype); + +RESET ROLE; +SET ROLE security_test_update; + +-- Test: SET should succeed with UPDATE permission +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Alice'}) + SET p.age = 31 + RETURN p.name, p.age +$$) AS (name agtype, age agtype); + +-- Test: SET on edge should succeed +SELECT * FROM cypher('security_test', $$ + MATCH (a:Person {name: 'Alice'})-[k:KNOWS]->(b:Person {name: 'Bob'}) + SET k.since = 2019 + RETURN k.since +$$) AS (since agtype); + +-- Test: SET with map update should succeed +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Bob'}) + SET p += {hobby: 'reading'} + RETURN p.name, p.hobby +$$) AS (name agtype, hobby agtype); + +-- ============================================================================ +-- PART 5: UPDATE Permission Tests (REMOVE clause) +-- ============================================================================ + +RESET ROLE; +SET ROLE security_test_readonly; + +-- Test: REMOVE should fail with only SELECT permission +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Bob'}) + REMOVE p.hobby + RETURN p +$$) AS (p agtype); + +RESET ROLE; +SET ROLE security_test_update; + +-- Test: REMOVE should succeed with UPDATE permission +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Bob'}) + REMOVE p.hobby + RETURN p.name, p.hobby +$$) AS (name agtype, hobby agtype); + +-- ============================================================================ +-- PART 6: DELETE Permission Tests +-- ============================================================================ + +RESET ROLE; +SET ROLE security_test_readonly; + +-- Test: DELETE should fail with only SELECT permission +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Charlie'}) + DELETE p +$$) AS (a agtype); + +RESET ROLE; +SET ROLE security_test_update; + +-- Test: DELETE should fail with only UPDATE permission (need DELETE) +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Charlie'}) + DELETE p +$$) AS (a agtype); + +RESET ROLE; +SET ROLE security_test_delete; + +-- Test: DELETE vertex should succeed with DELETE permission +-- First delete the edge connected to Charlie +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Charlie'})-[k:KNOWS]->() + DELETE k +$$) AS (a agtype); + +-- Now delete the vertex +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Charlie'}) + DELETE p +$$) AS (a agtype); + +-- Verify deletion +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Charlie'}) RETURN p +$$) AS (p agtype); + +-- ============================================================================ +-- PART 7: DETACH DELETE Tests +-- ============================================================================ + +RESET ROLE; + +-- Create a new vertex with edge for DETACH DELETE test +SELECT * FROM cypher('security_test', $$ + CREATE (:Person {name: 'Dave', age: 40}) +$$) AS (a agtype); + +SELECT * FROM cypher('security_test', $$ + MATCH (a:Person {name: 'Alice'}), (d:Person {name: 'Dave'}) + CREATE (a)-[:KNOWS {since: 2022}]->(d) +$$) AS (a agtype); + +SET ROLE security_test_detach_delete; + +-- Test: DETACH DELETE should fail without DELETE on edge table +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Dave'}) + DETACH DELETE p +$$) AS (a agtype); + +RESET ROLE; +GRANT DELETE ON security_test."KNOWS" TO security_test_detach_delete; +SET ROLE security_test_detach_delete; + +-- Test: DETACH DELETE should succeed now when user has DELETE on both vertex and edge tables +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Dave'}) + DETACH DELETE p +$$) AS (a agtype); + +-- Verify deletion +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Dave'}) RETURN p +$$) AS (p agtype); + +-- ============================================================================ +-- PART 8: MERGE Permission Tests +-- ============================================================================ + +RESET ROLE; +SET ROLE security_test_readonly; + +-- Test: MERGE that would create should fail without INSERT +SELECT * FROM cypher('security_test', $$ + MERGE (p:Person {name: 'Eve'}) + RETURN p +$$) AS (p agtype); + +RESET ROLE; +SET ROLE security_test_insert; + +-- Test: MERGE that creates should succeed with INSERT permission +SELECT * FROM cypher('security_test', $$ + MERGE (p:Person {name: 'Eve', age: 28}) + RETURN p.name, p.age +$$) AS (name agtype, age agtype); + +-- Test: MERGE that matches existing should succeed (only needs SELECT) +SELECT * FROM cypher('security_test', $$ + MERGE (p:Person {name: 'Eve'}) + RETURN p.name +$$) AS (name agtype); + +-- ============================================================================ +-- PART 9: Full Permission Role Tests +-- ============================================================================ + +RESET ROLE; +SET ROLE security_test_full; + +-- Full permission role should be able to do everything +SELECT * FROM cypher('security_test', $$ + CREATE (:Person {name: 'Frank', age: 50}) +$$) AS (a agtype); + +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Frank'}) + SET p.age = 51 + RETURN p.name, p.age +$$) AS (name agtype, age agtype); + +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Frank'}) + DELETE p +$$) AS (a agtype); + +-- ============================================================================ +-- PART 10: Permission on Specific Labels +-- ============================================================================ + +RESET ROLE; + +-- Create a role with permission only on Person label, not Document +CREATE ROLE security_test_person_only LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_person_only; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_person_only; +GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA ag_catalog TO security_test_person_only; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_person_only; +-- Only grant permissions on Person table +GRANT SELECT, INSERT, UPDATE, DELETE ON security_test."Person" TO security_test_person_only; +GRANT SELECT ON security_test."KNOWS" TO security_test_person_only; +GRANT SELECT ON security_test._ag_label_vertex TO security_test_person_only; +GRANT SELECT ON security_test._ag_label_edge TO security_test_person_only; +GRANT USAGE ON ALL SEQUENCES IN SCHEMA security_test TO security_test_person_only; + +SET ROLE security_test_person_only; + +-- Test: Operations on Person should succeed +SELECT * FROM cypher('security_test', $$ + MATCH (p:Person {name: 'Alice'}) RETURN p.name +$$) AS (name agtype); + +-- Test: SELECT on Document should fail (no permission) +SELECT * FROM cypher('security_test', $$ + MATCH (d:Document) RETURN d.title +$$) AS (title agtype); + +-- Test: CREATE Document should fail (no permission on Document table) +SELECT * FROM cypher('security_test', $$ + CREATE (:Document {title: 'New Doc'}) +$$) AS (a agtype); + +-- ============================================================================ +-- PART 11: Function EXECUTE Permission Tests +-- ============================================================================ + +RESET ROLE; + +-- Create role with no function execute permissions +CREATE ROLE security_test_noexec LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_noexec; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_noexec; + +-- Revoke execute from PUBLIC on functions we want to test +REVOKE EXECUTE ON FUNCTION ag_catalog.create_graph(name) FROM PUBLIC; +REVOKE EXECUTE ON FUNCTION ag_catalog.drop_graph(name, boolean) FROM PUBLIC; +REVOKE EXECUTE ON FUNCTION ag_catalog.create_vlabel(cstring, cstring) FROM PUBLIC; +REVOKE EXECUTE ON FUNCTION ag_catalog.create_elabel(cstring, cstring) FROM PUBLIC; + +SET ROLE security_test_noexec; + +-- Test: create_graph should fail without EXECUTE permission +SELECT create_graph('unauthorized_graph'); + +-- Test: drop_graph should fail without EXECUTE permission +SELECT drop_graph('security_test', true); + +-- Test: create_vlabel should fail without EXECUTE permission +SELECT create_vlabel('security_test', 'NewLabel'); + +-- Test: create_elabel should fail without EXECUTE permission +SELECT create_elabel('security_test', 'NewEdge'); + +RESET ROLE; + +-- Grant execute on specific function and test +GRANT EXECUTE ON FUNCTION ag_catalog.create_vlabel(cstring, cstring) TO security_test_noexec; + +SET ROLE security_test_noexec; + +-- Test: create_vlabel should now get past execute check (will fail on schema permission instead) +SELECT create_vlabel('security_test', 'TestLabel'); + +-- Test: create_graph should still fail with execute permission denied +SELECT create_graph('unauthorized_graph'); + +RESET ROLE; + +-- Restore execute permissions to PUBLIC +GRANT EXECUTE ON FUNCTION ag_catalog.create_graph(name) TO PUBLIC; +GRANT EXECUTE ON FUNCTION ag_catalog.drop_graph(name, boolean) TO PUBLIC; +GRANT EXECUTE ON FUNCTION ag_catalog.create_vlabel(cstring, cstring) TO PUBLIC; +GRANT EXECUTE ON FUNCTION ag_catalog.create_elabel(cstring, cstring) TO PUBLIC; + +-- ============================================================================ +-- PART 12: startNode/endNode Permission Tests +-- ============================================================================ + +-- Create role with SELECT on base tables but NOT on Person label +CREATE ROLE security_test_edge_only LOGIN; +GRANT USAGE ON SCHEMA security_test TO security_test_edge_only; +GRANT USAGE ON SCHEMA ag_catalog TO security_test_edge_only; +GRANT SELECT ON ALL TABLES IN SCHEMA ag_catalog TO security_test_edge_only; +GRANT SELECT ON security_test."KNOWS" TO security_test_edge_only; +GRANT SELECT ON security_test._ag_label_edge TO security_test_edge_only; +GRANT SELECT ON security_test._ag_label_vertex TO security_test_edge_only; +-- Note: NOT granting SELECT on security_test."Person" + +SET ROLE security_test_edge_only; + +-- Test: endNode fails without SELECT on Person table +SELECT * FROM cypher('security_test', $$ + MATCH ()-[e:KNOWS]->() + RETURN endNode(e) +$$) AS (end_vertex agtype); + +-- Test: startNode fails without SELECT on Person table +SELECT * FROM cypher('security_test', $$ + MATCH ()-[e:KNOWS]->() + RETURN startNode(e) +$$) AS (start_vertex agtype); + +RESET ROLE; + +-- Grant SELECT on Person and verify success +GRANT SELECT ON security_test."Person" TO security_test_edge_only; + +SET ROLE security_test_edge_only; + +-- Test: Should now succeed with SELECT permission +SELECT * FROM cypher('security_test', $$ + MATCH ()-[e:KNOWS]->() + RETURN startNode(e).name, endNode(e).name +$$) AS (start_name agtype, end_name agtype); + +RESET ROLE; + +-- ============================================================================ +-- Cleanup +-- ============================================================================ + +RESET ROLE; + +-- Drop all owned objects and privileges for each role, then drop the role +DROP OWNED BY security_test_noread CASCADE; +DROP ROLE security_test_noread; + +DROP OWNED BY security_test_base_only CASCADE; +DROP ROLE security_test_base_only; + +DROP OWNED BY security_test_readonly CASCADE; +DROP ROLE security_test_readonly; + +DROP OWNED BY security_test_insert CASCADE; +DROP ROLE security_test_insert; + +DROP OWNED BY security_test_update CASCADE; +DROP ROLE security_test_update; + +DROP OWNED BY security_test_delete CASCADE; +DROP ROLE security_test_delete; + +DROP OWNED BY security_test_detach_delete CASCADE; +DROP ROLE security_test_detach_delete; + +DROP OWNED BY security_test_full CASCADE; +DROP ROLE security_test_full; + +DROP OWNED BY security_test_person_only CASCADE; +DROP ROLE security_test_person_only; + +DROP OWNED BY security_test_noexec CASCADE; +DROP ROLE security_test_noexec; + +DROP OWNED BY security_test_edge_only CASCADE; +DROP ROLE security_test_edge_only; + +-- Drop test graph +SELECT drop_graph('security_test', true); + +-- +-- Row-Level Security (RLS) Tests +-- + +-- +-- Setup: Create test graph, data and roles for RLS tests +-- +SELECT create_graph('rls_graph'); + +-- Create test roles +CREATE ROLE rls_user1 LOGIN; +CREATE ROLE rls_user2 LOGIN; +CREATE ROLE rls_admin LOGIN BYPASSRLS; -- Role that bypasses RLS + +-- Create base test data FIRST (as superuser) - this creates the label tables +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'Alice', owner: 'rls_user1', department: 'Engineering', level: 1}) +$$) AS (a agtype); + +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'Bob', owner: 'rls_user2', department: 'Engineering', level: 2}) +$$) AS (a agtype); + +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'Charlie', owner: 'rls_user1', department: 'Sales', level: 1}) +$$) AS (a agtype); + +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'Diana', owner: 'rls_user2', department: 'Sales', level: 3}) +$$) AS (a agtype); + +-- Create a second vertex label for multi-label tests +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Document {title: 'Public Doc', classification: 'public', owner: 'rls_user1'}) +$$) AS (a agtype); + +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Document {title: 'Secret Doc', classification: 'secret', owner: 'rls_user2'}) +$$) AS (a agtype); + +-- Create edges +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Alice'}), (b:Person {name: 'Bob'}) + CREATE (a)-[:KNOWS {since: 2020, strength: 'weak'}]->(b) +$$) AS (a agtype); + +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Charlie'}), (b:Person {name: 'Diana'}) + CREATE (a)-[:KNOWS {since: 2021, strength: 'strong'}]->(b) +$$) AS (a agtype); + +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Alice'}), (b:Person {name: 'Charlie'}) + CREATE (a)-[:KNOWS {since: 2022, strength: 'strong'}]->(b) +$$) AS (a agtype); + +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Alice'}), (d:Document {title: 'Public Doc'}) + CREATE (a)-[:AUTHORED]->(d) +$$) AS (a agtype); + +-- Grant permissions AFTER creating tables (so Person, Document, KNOWS, AUTHORED exist) +GRANT USAGE ON SCHEMA rls_graph TO rls_user1, rls_user2, rls_admin; +GRANT ALL ON ALL TABLES IN SCHEMA rls_graph TO rls_user1, rls_user2, rls_admin; +GRANT USAGE ON SCHEMA ag_catalog TO rls_user1, rls_user2, rls_admin; +GRANT USAGE ON ALL SEQUENCES IN SCHEMA rls_graph TO rls_user1, rls_user2, rls_admin; + +-- ============================================================================ +-- PART 1: Vertex SELECT Policies (USING clause) +-- ============================================================================ + +-- Enable RLS on Person label +ALTER TABLE rls_graph."Person" ENABLE ROW LEVEL SECURITY; +ALTER TABLE rls_graph."Person" FORCE ROW LEVEL SECURITY; + +-- 1.1: Basic ownership filtering +CREATE POLICY person_select_own ON rls_graph."Person" + FOR SELECT + USING (properties->>'"owner"' = current_user); + +-- Test as rls_user1 - should only see Alice and Charlie (owned by rls_user1) +SET ROLE rls_user1; +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + +-- Test as rls_user2 - should only see Bob and Diana (owned by rls_user2) +SET ROLE rls_user2; +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + +RESET ROLE; + +-- 1.2: Default deny - no permissive policies means no access +DROP POLICY person_select_own ON rls_graph."Person"; + +-- With no policies, RLS blocks all access +SET ROLE rls_user1; +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + +RESET ROLE; + +-- ============================================================================ +-- PART 2: Vertex INSERT Policies (WITH CHECK) - CREATE +-- ============================================================================ + +-- Allow SELECT for all (so we can verify results) +CREATE POLICY person_select_all ON rls_graph."Person" + FOR SELECT USING (true); + +-- 2.1: Basic WITH CHECK - users can only insert rows they own +CREATE POLICY person_insert_own ON rls_graph."Person" + FOR INSERT + WITH CHECK (properties->>'"owner"' = current_user); + +-- Test as rls_user1 - should succeed (owner matches current_user) +SET ROLE rls_user1; +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'User1Created', owner: 'rls_user1', department: 'Test', level: 1}) +$$) AS (a agtype); + +-- Test as rls_user1 - should FAIL (owner doesn't match current_user) +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'User1Fake', owner: 'rls_user2', department: 'Test', level: 1}) +$$) AS (a agtype); + +RESET ROLE; + +-- Verify only User1Created was created +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department = 'Test' RETURN p.name ORDER BY p.name +$$) AS (name agtype); + +-- 2.2: Default deny for INSERT - no INSERT policy blocks all inserts +DROP POLICY person_insert_own ON rls_graph."Person"; + +SET ROLE rls_user1; +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'ShouldFail', owner: 'rls_user1', department: 'Blocked', level: 1}) +$$) AS (a agtype); +RESET ROLE; + +-- Verify nothing was created in Blocked department +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department = 'Blocked' RETURN p.name +$$) AS (name agtype); + +-- cleanup +DROP POLICY person_select_all ON rls_graph."Person"; +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department = 'Test' DELETE p +$$) AS (a agtype); + +-- ============================================================================ +-- PART 3: Vertex UPDATE Policies - SET +-- ============================================================================ + +CREATE POLICY person_select_all ON rls_graph."Person" + FOR SELECT USING (true); + +-- 3.1: USING clause only - filter which rows can be updated +CREATE POLICY person_update_using ON rls_graph."Person" + FOR UPDATE + USING (properties->>'"owner"' = current_user); + +SET ROLE rls_user1; + +-- Should succeed - rls_user1 owns Alice +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Alice'}) SET p.updated = true RETURN p.name, p.updated +$$) AS (name agtype, updated agtype); + +-- Should silently skip - rls_user1 doesn't own Bob (USING filters it out) +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Bob'}) SET p.updated = true RETURN p.name, p.updated +$$) AS (name agtype, updated agtype); + +RESET ROLE; + +-- Verify Alice was updated, Bob was not +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.name IN ['Alice', 'Bob'] RETURN p.name, p.updated ORDER BY p.name +$$) AS (name agtype, updated agtype); + +-- 3.2: WITH CHECK clause - validate new values +DROP POLICY person_update_using ON rls_graph."Person"; + +CREATE POLICY person_update_check ON rls_graph."Person" + FOR UPDATE + USING (true) -- Can update any row + WITH CHECK (properties->>'"owner"' = current_user); -- But new value must keep owner + +SET ROLE rls_user1; + +-- Should succeed - modifying property but keeping owner +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Alice'}) SET p.verified = true RETURN p.name, p.verified +$$) AS (name agtype, verified agtype); + +-- Should FAIL - trying to change owner to someone else +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Alice'}) SET p.owner = 'rls_user2' RETURN p.owner +$$) AS (owner agtype); + +RESET ROLE; + +-- Verify owner wasn't changed +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Alice'}) RETURN p.owner +$$) AS (owner agtype); + +-- 3.3: Both USING and WITH CHECK together +DROP POLICY person_update_check ON rls_graph."Person"; + +CREATE POLICY person_update_both ON rls_graph."Person" + FOR UPDATE + USING (properties->>'"owner"' = current_user) + WITH CHECK (properties->>'"owner"' = current_user); + +SET ROLE rls_user1; + +-- Should succeed - owns Alice, keeping owner +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Alice'}) SET p.status = 'active' RETURN p.name, p.status +$$) AS (name agtype, status agtype); + +-- Should silently skip - doesn't own Bob (USING filters) +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Bob'}) SET p.status = 'active' RETURN p.name, p.status +$$) AS (name agtype, status agtype); + +RESET ROLE; + +-- ============================================================================ +-- PART 4: Vertex UPDATE Policies - REMOVE +-- ============================================================================ + +-- Keep existing update policy, test REMOVE operation + +SET ROLE rls_user1; + +-- Should succeed - owns Alice +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Alice'}) REMOVE p.status RETURN p.name, p.status +$$) AS (name agtype, status agtype); + +-- Should silently skip - doesn't own Bob +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Bob'}) REMOVE p.department RETURN p.name, p.department +$$) AS (name agtype, dept agtype); + +RESET ROLE; + +-- Verify Bob still has department +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'Bob'}) RETURN p.department +$$) AS (dept agtype); + +-- cleanup +DROP POLICY person_select_all ON rls_graph."Person"; +DROP POLICY person_update_both ON rls_graph."Person"; + +-- ============================================================================ +-- PART 5: Vertex DELETE Policies +-- ============================================================================ + +CREATE POLICY person_select_all ON rls_graph."Person" + FOR SELECT USING (true); + +-- Create test data for delete tests +CREATE POLICY person_insert_all ON rls_graph."Person" + FOR INSERT WITH CHECK (true); + +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'DeleteTest1', owner: 'rls_user1', department: 'DeleteTest', level: 1}) +$$) AS (a agtype); + +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'DeleteTest2', owner: 'rls_user2', department: 'DeleteTest', level: 1}) +$$) AS (a agtype); + +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'DeleteTest3', owner: 'rls_user1', department: 'DeleteTest', level: 1}) +$$) AS (a agtype); + +DROP POLICY person_insert_all ON rls_graph."Person"; + +-- 5.1: Basic USING filtering for DELETE +CREATE POLICY person_delete_own ON rls_graph."Person" + FOR DELETE + USING (properties->>'"owner"' = current_user); + +SET ROLE rls_user1; + +-- Should succeed - owns DeleteTest1 +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'DeleteTest1'}) DELETE p +$$) AS (a agtype); + +-- Should silently skip - doesn't own DeleteTest2 +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'DeleteTest2'}) DELETE p +$$) AS (a agtype); + +RESET ROLE; + +-- Verify DeleteTest1 deleted, DeleteTest2 still exists +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department = 'DeleteTest' RETURN p.name ORDER BY p.name +$$) AS (name agtype); + +-- 5.2: Default deny for DELETE - no policy blocks all deletes +DROP POLICY person_delete_own ON rls_graph."Person"; + +SET ROLE rls_user1; + +-- Should silently skip - no DELETE policy means default deny +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'DeleteTest3'}) DELETE p +$$) AS (a agtype); + +RESET ROLE; + +-- Verify DeleteTest3 still exists +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'DeleteTest3'}) RETURN p.name +$$) AS (name agtype); + +-- cleanup +DROP POLICY person_select_all ON rls_graph."Person"; +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department = 'DeleteTest' DELETE p +$$) AS (a agtype); + +-- ============================================================================ +-- PART 6: MERGE Policies +-- ============================================================================ + +CREATE POLICY person_select_all ON rls_graph."Person" + FOR SELECT USING (true); + +CREATE POLICY person_insert_own ON rls_graph."Person" + FOR INSERT + WITH CHECK (properties->>'"owner"' = current_user); + +-- 6.1: MERGE creating new vertex - INSERT policy applies +SET ROLE rls_user1; + +-- Should succeed - creating with correct owner +SELECT * FROM cypher('rls_graph', $$ + MERGE (p:Person {name: 'MergeNew1', owner: 'rls_user1', department: 'Merge', level: 1}) + RETURN p.name +$$) AS (name agtype); + +-- Should FAIL - creating with wrong owner +SELECT * FROM cypher('rls_graph', $$ + MERGE (p:Person {name: 'MergeNew2', owner: 'rls_user2', department: 'Merge', level: 1}) + RETURN p.name +$$) AS (name agtype); + +RESET ROLE; + +-- 6.2: MERGE matching existing - only SELECT needed +SET ROLE rls_user1; + +-- Should succeed - Alice exists and SELECT allowed +SELECT * FROM cypher('rls_graph', $$ + MERGE (p:Person {name: 'Alice'}) + RETURN p.name, p.owner +$$) AS (name agtype, owner agtype); + +RESET ROLE; + +-- Verify only MergeNew1 was created +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department = 'Merge' RETURN p.name ORDER BY p.name +$$) AS (name agtype); + +-- cleanup +DROP POLICY person_select_all ON rls_graph."Person"; +DROP POLICY person_insert_own ON rls_graph."Person"; +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department = 'Merge' DELETE p +$$) AS (a agtype); + +-- ============================================================================ +-- PART 7: Edge SELECT Policies +-- ============================================================================ + +-- Disable vertex RLS, enable edge RLS +ALTER TABLE rls_graph."Person" DISABLE ROW LEVEL SECURITY; +ALTER TABLE rls_graph."KNOWS" ENABLE ROW LEVEL SECURITY; +ALTER TABLE rls_graph."KNOWS" FORCE ROW LEVEL SECURITY; + +-- Policy: Only see edges from 2021 or later +CREATE POLICY knows_select_recent ON rls_graph."KNOWS" + FOR SELECT + USING ((properties->>'"since"')::int >= 2021); + +SET ROLE rls_user1; + +-- Should only see 2021 and 2022 edges (not 2020) +SELECT * FROM cypher('rls_graph', $$ + MATCH ()-[k:KNOWS]->() RETURN k.since ORDER BY k.since +$$) AS (since agtype); + +RESET ROLE; + +-- ============================================================================ +-- PART 8: Edge INSERT Policies (CREATE edge) +-- ============================================================================ + +DROP POLICY knows_select_recent ON rls_graph."KNOWS"; + +CREATE POLICY knows_select_all ON rls_graph."KNOWS" + FOR SELECT USING (true); + +-- Policy: Can only create edges with strength = 'strong' +CREATE POLICY knows_insert_strong ON rls_graph."KNOWS" + FOR INSERT + WITH CHECK (properties->>'"strength"' = 'strong'); + +SET ROLE rls_user1; + +-- Should succeed - strength is 'strong' +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Bob'}), (b:Person {name: 'Diana'}) + CREATE (a)-[:KNOWS {since: 2023, strength: 'strong'}]->(b) +$$) AS (a agtype); + +-- Should FAIL - strength is 'weak' +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Diana'}), (b:Person {name: 'Alice'}) + CREATE (a)-[:KNOWS {since: 2023, strength: 'weak'}]->(b) +$$) AS (a agtype); + +RESET ROLE; + +-- Verify only strong edge was created +SELECT * FROM cypher('rls_graph', $$ + MATCH ()-[k:KNOWS]->() WHERE k.since = 2023 RETURN k.strength ORDER BY k.strength +$$) AS (strength agtype); + +-- cleanup +DROP POLICY knows_insert_strong ON rls_graph."KNOWS"; + +-- ============================================================================ +-- PART 9: Edge UPDATE Policies (SET on edge) +-- ============================================================================ + +-- Policy: Can only update edges with strength = 'strong' +CREATE POLICY knows_update_strong ON rls_graph."KNOWS" + FOR UPDATE + USING (properties->>'"strength"' = 'strong') + WITH CHECK (properties->>'"strength"' = 'strong'); + +SET ROLE rls_user1; + +-- Should succeed - edge has strength 'strong' +SELECT * FROM cypher('rls_graph', $$ + MATCH ()-[k:KNOWS {since: 2021}]->() SET k.notes = 'updated' RETURN k.since, k.notes +$$) AS (since agtype, notes agtype); + +-- Should silently skip - edge has strength 'weak' +SELECT * FROM cypher('rls_graph', $$ + MATCH ()-[k:KNOWS {since: 2020}]->() SET k.notes = 'updated' RETURN k.since, k.notes +$$) AS (since agtype, notes agtype); + +RESET ROLE; + +-- Verify only 2021 edge was updated +SELECT * FROM cypher('rls_graph', $$ + MATCH ()-[k:KNOWS]->() WHERE k.since IN [2020, 2021] RETURN k.since, k.notes ORDER BY k.since +$$) AS (since agtype, notes agtype); + +-- cleanup +DROP POLICY knows_select_all ON rls_graph."KNOWS"; +DROP POLICY knows_update_strong ON rls_graph."KNOWS"; + +-- ============================================================================ +-- PART 10: Edge DELETE Policies +-- ============================================================================ + +CREATE POLICY knows_select_all ON rls_graph."KNOWS" + FOR SELECT USING (true); + +-- Create test edges for delete +CREATE POLICY knows_insert_all ON rls_graph."KNOWS" + FOR INSERT WITH CHECK (true); + +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Bob'}), (b:Person {name: 'Charlie'}) + CREATE (a)-[:KNOWS {since: 2018, strength: 'weak'}]->(b) +$$) AS (a agtype); + +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Diana'}), (b:Person {name: 'Charlie'}) + CREATE (a)-[:KNOWS {since: 2019, strength: 'strong'}]->(b) +$$) AS (a agtype); + +DROP POLICY knows_insert_all ON rls_graph."KNOWS"; + +-- Policy: Can only delete edges with strength = 'weak' +CREATE POLICY knows_delete_weak ON rls_graph."KNOWS" + FOR DELETE + USING (properties->>'"strength"' = 'weak'); + +SET ROLE rls_user1; + +-- Should succeed - edge has strength 'weak' +SELECT * FROM cypher('rls_graph', $$ + MATCH ()-[k:KNOWS {since: 2018}]->() DELETE k +$$) AS (a agtype); + +-- Should silently skip - edge has strength 'strong' +SELECT * FROM cypher('rls_graph', $$ + MATCH ()-[k:KNOWS {since: 2019}]->() DELETE k +$$) AS (a agtype); + +RESET ROLE; + +-- Verify 2018 edge deleted, 2019 edge still exists +SELECT * FROM cypher('rls_graph', $$ + MATCH ()-[k:KNOWS]->() WHERE k.since IN [2018, 2019] RETURN k.since ORDER BY k.since +$$) AS (since agtype); + +-- cleanup +DROP POLICY knows_delete_weak ON rls_graph."KNOWS"; + +-- ============================================================================ +-- PART 11: DETACH DELETE +-- ============================================================================ + +-- Re-enable Person RLS +ALTER TABLE rls_graph."Person" ENABLE ROW LEVEL SECURITY; +CREATE POLICY person_all ON rls_graph."Person" + FOR ALL USING (true) WITH CHECK (true); + +-- Create test data with a protected edge +CREATE POLICY knows_insert_all ON rls_graph."KNOWS" + FOR INSERT WITH CHECK (true); + +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'DetachTest1', owner: 'test', department: 'Detach', level: 1}) +$$) AS (a agtype); + +SELECT * FROM cypher('rls_graph', $$ + CREATE (:Person {name: 'DetachTest2', owner: 'test', department: 'Detach', level: 1}) +$$) AS (a agtype); + +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'DetachTest1'}), (b:Person {name: 'DetachTest2'}) + CREATE (a)-[:KNOWS {since: 2010, strength: 'protected'}]->(b) +$$) AS (a agtype); + +DROP POLICY knows_insert_all ON rls_graph."KNOWS"; + +-- Policy: Cannot delete edges with strength = 'protected' +CREATE POLICY knows_delete_not_protected ON rls_graph."KNOWS" + FOR DELETE + USING (properties->>'"strength"' != 'protected'); + +SET ROLE rls_user1; + +-- Should ERROR - DETACH DELETE cannot silently skip (would leave dangling edge) +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'DetachTest1'}) DETACH DELETE p +$$) AS (a agtype); + +RESET ROLE; + +-- Verify vertex still exists (delete was blocked) +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'DetachTest1'}) RETURN p.name +$$) AS (name agtype); + +-- cleanup +DROP POLICY person_all ON rls_graph."Person"; +DROP POLICY knows_select_all ON rls_graph."KNOWS"; +DROP POLICY knows_delete_not_protected ON rls_graph."KNOWS"; +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department = 'Detach' DETACH DELETE p +$$) AS (a agtype); + +-- ============================================================================ +-- PART 12: Multiple Labels in Single Query +-- ============================================================================ + +-- Enable RLS on Document too +ALTER TABLE rls_graph."Document" ENABLE ROW LEVEL SECURITY; +ALTER TABLE rls_graph."Document" FORCE ROW LEVEL SECURITY; + +-- Policy: Users see their own Person records +CREATE POLICY person_own ON rls_graph."Person" + FOR SELECT + USING (properties->>'"owner"' = current_user); + +-- Policy: Users see only public documents +CREATE POLICY doc_public ON rls_graph."Document" + FOR SELECT + USING (properties->>'"classification"' = 'public'); + +SET ROLE rls_user1; + +-- Should only see Alice and Charlie (Person) with Public Doc (Document) +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + +SELECT * FROM cypher('rls_graph', $$ + MATCH (d:Document) RETURN d.title ORDER BY d.title +$$) AS (title agtype); + +-- Combined query - should respect both policies +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person)-[:AUTHORED]->(d:Document) + RETURN p.name, d.title +$$) AS (person agtype, doc agtype); + +RESET ROLE; + +-- ============================================================================ +-- PART 13: Permissive vs Restrictive Policies +-- ============================================================================ + +DROP POLICY person_own ON rls_graph."Person"; +DROP POLICY doc_public ON rls_graph."Document"; + +ALTER TABLE rls_graph."Document" DISABLE ROW LEVEL SECURITY; +ALTER TABLE rls_graph."KNOWS" DISABLE ROW LEVEL SECURITY; + +-- 13.1: Multiple permissive policies (OR logic) +CREATE POLICY person_permissive_own ON rls_graph."Person" + AS PERMISSIVE FOR SELECT + USING (properties->>'"owner"' = current_user); + +CREATE POLICY person_permissive_eng ON rls_graph."Person" + AS PERMISSIVE FOR SELECT + USING (properties->>'"department"' = 'Engineering'); + +SET ROLE rls_user1; + +-- Should see: Alice (own), Charlie (own), Bob (Engineering) +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.department IN ['Engineering', 'Sales'] + RETURN p.name ORDER BY p.name +$$) AS (name agtype); + +RESET ROLE; + +-- 13.2: Add restrictive policy (AND with permissive) +CREATE POLICY person_restrictive_level ON rls_graph."Person" + AS RESTRICTIVE FOR SELECT + USING ((properties->>'"level"')::int <= 2); + +SET ROLE rls_user1; + +-- Should see: Alice (own, level 1), Bob (Engineering, level 2), Charlie (own, level 1) +-- Diana (level 3) blocked by restrictive +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name, p.level ORDER BY p.name +$$) AS (name agtype, level agtype); + +RESET ROLE; + +-- 13.3: Multiple restrictive policies (all must pass) +CREATE POLICY person_restrictive_sales ON rls_graph."Person" + AS RESTRICTIVE FOR SELECT + USING (properties->>'"department"' != 'Sales'); + +SET ROLE rls_user1; + +-- Should see: Alice (own, level 1, not Sales), Bob (Engineering, level 2, not Sales) +-- Charlie blocked by Sales restriction +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + +RESET ROLE; + +-- ============================================================================ +-- PART 14: BYPASSRLS Role and Superuser Behavior +-- ============================================================================ + +DROP POLICY person_permissive_own ON rls_graph."Person"; +DROP POLICY person_permissive_eng ON rls_graph."Person"; +DROP POLICY person_restrictive_level ON rls_graph."Person"; +DROP POLICY person_restrictive_sales ON rls_graph."Person"; + +-- Restrictive policy that blocks most access +CREATE POLICY person_very_restrictive ON rls_graph."Person" + FOR SELECT + USING (properties->>'"name"' = 'Nobody'); + +-- 14.1: Regular user sees nothing +SET ROLE rls_user1; + +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + +RESET ROLE; + +-- 14.2: BYPASSRLS role sees everything +SET ROLE rls_admin; + +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + +RESET ROLE; + +-- 14.3: Superuser sees everything (implicit bypass) +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) RETURN p.name ORDER BY p.name +$$) AS (name agtype); + +-- ============================================================================ +-- PART 15: Complex Multi-Operation Queries +-- ============================================================================ + +DROP POLICY person_very_restrictive ON rls_graph."Person"; + +CREATE POLICY person_select_all ON rls_graph."Person" + FOR SELECT USING (true); + +CREATE POLICY person_insert_own ON rls_graph."Person" + FOR INSERT + WITH CHECK (properties->>'"owner"' = current_user); + +CREATE POLICY person_update_own ON rls_graph."Person" + FOR UPDATE + USING (properties->>'"owner"' = current_user) + WITH CHECK (properties->>'"owner"' = current_user); + +-- 15.1: MATCH + CREATE in one query +SET ROLE rls_user1; + +-- Should succeed - creating with correct owner +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Alice'}) + CREATE (a)-[:KNOWS]->(:Person {name: 'NewFromMatch', owner: 'rls_user1', department: 'Complex', level: 1}) +$$) AS (a agtype); + +RESET ROLE; + +-- Verify creation +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person {name: 'NewFromMatch'}) RETURN p.name, p.owner +$$) AS (name agtype, owner agtype); + +-- 15.2: MATCH + SET in one query +SET ROLE rls_user1; + +-- Should succeed on Alice (own), skip Bob (not own) +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.name IN ['Alice', 'Bob'] + SET p.complexTest = true + RETURN p.name, p.complexTest +$$) AS (name agtype, test agtype); + +RESET ROLE; + +-- Verify only Alice was updated +SELECT * FROM cypher('rls_graph', $$ + MATCH (p:Person) WHERE p.name IN ['Alice', 'Bob'] + RETURN p.name, p.complexTest ORDER BY p.name +$$) AS (name agtype, test agtype); + +-- cleanup +DROP POLICY IF EXISTS person_select_all ON rls_graph."Person"; +DROP POLICY IF EXISTS person_insert_own ON rls_graph."Person"; +DROP POLICY IF EXISTS person_update_own ON rls_graph."Person"; + +-- ============================================================================ +-- PART 16: startNode/endNode RLS Enforcement +-- ============================================================================ + +ALTER TABLE rls_graph."Person" DISABLE ROW LEVEL SECURITY; + +-- Enable RLS on Person with restrictive policy +ALTER TABLE rls_graph."Person" ENABLE ROW LEVEL SECURITY; +ALTER TABLE rls_graph."Person" FORCE ROW LEVEL SECURITY; + +-- Policy: users can only see their own Person records +CREATE POLICY person_own ON rls_graph."Person" + FOR SELECT + USING (properties->>'"owner"' = current_user); + +-- Enable edge access for testing +ALTER TABLE rls_graph."KNOWS" ENABLE ROW LEVEL SECURITY; +CREATE POLICY knows_all ON rls_graph."KNOWS" + FOR SELECT USING (true); + +-- 16.1: startNode blocked by RLS - should error +SET ROLE rls_user1; + +-- rls_user1 can see the edge (Alice->Bob) but cannot see Bob (owned by rls_user2) +-- endNode should error because Bob is blocked by RLS +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Alice'})-[e:KNOWS]->(b) + RETURN endNode(e) +$$) AS (end_vertex agtype); + +-- 16.2: endNode blocked by RLS - should error +-- rls_user1 cannot see Bob, so startNode on an edge starting from Bob should error +SET ROLE rls_user2; + +-- rls_user2 can see Bob but not Alice (owned by rls_user1) +-- startNode should error because Alice is blocked by RLS +SELECT * FROM cypher('rls_graph', $$ + MATCH (a)-[e:KNOWS]->(b:Person {name: 'Bob'}) + RETURN startNode(e) +$$) AS (start_vertex agtype); + +-- 16.3: startNode/endNode succeed when RLS allows access +SET ROLE rls_user1; + +-- Alice->Charlie edge: rls_user1 owns both, should succeed +SELECT * FROM cypher('rls_graph', $$ + MATCH (a:Person {name: 'Alice'})-[e:KNOWS]->(c:Person {name: 'Charlie'}) + RETURN startNode(e).name, endNode(e).name +$$) AS (start_name agtype, end_name agtype); + +RESET ROLE; + +-- cleanup +DROP POLICY person_own ON rls_graph."Person"; +DROP POLICY knows_all ON rls_graph."KNOWS"; +ALTER TABLE rls_graph."KNOWS" DISABLE ROW LEVEL SECURITY; + +-- ============================================================================ +-- RLS CLEANUP +-- ============================================================================ + +RESET ROLE; + +-- Disable RLS on all tables +ALTER TABLE rls_graph."Person" DISABLE ROW LEVEL SECURITY; +ALTER TABLE rls_graph."Document" DISABLE ROW LEVEL SECURITY; +ALTER TABLE rls_graph."KNOWS" DISABLE ROW LEVEL SECURITY; + +-- Drop roles +DROP OWNED BY rls_user1 CASCADE; +DROP ROLE rls_user1; + +DROP OWNED BY rls_user2 CASCADE; +DROP ROLE rls_user2; + +DROP OWNED BY rls_admin CASCADE; +DROP ROLE rls_admin; + +-- Drop test graph +SELECT drop_graph('rls_graph', true); diff --git a/src/backend/executor/cypher_create.c b/src/backend/executor/cypher_create.c index 2091ea29c..a90c2a196 100644 --- a/src/backend/executor/cypher_create.c +++ b/src/backend/executor/cypher_create.c @@ -19,6 +19,8 @@ #include "postgres.h" +#include "utils/rls.h" + #include "catalog/ag_label.h" #include "executor/cypher_executor.h" #include "executor/cypher_utils.h" @@ -120,6 +122,12 @@ static void begin_cypher_create(CustomScanState *node, EState *estate, cypher_node->prop_expr_state = ExecInitExpr(cypher_node->prop_expr, (PlanState *)node); } + + /* Setup RLS WITH CHECK policies if RLS is enabled */ + if (check_enable_rls(rel->rd_id, InvalidOid, true) == RLS_ENABLED) + { + setup_wcos(cypher_node->resultRelInfo, estate, node, CMD_INSERT); + } } } diff --git a/src/backend/executor/cypher_delete.c b/src/backend/executor/cypher_delete.c index 5f9aa561d..4766c6e7a 100644 --- a/src/backend/executor/cypher_delete.c +++ b/src/backend/executor/cypher_delete.c @@ -19,8 +19,11 @@ #include "postgres.h" -#include "storage/bufmgr.h" #include "common/hashfn.h" +#include "miscadmin.h" +#include "storage/bufmgr.h" +#include "utils/acl.h" +#include "utils/rls.h" #include "catalog/ag_label.h" #include "executor/cypher_executor.h" @@ -370,6 +373,16 @@ static void process_delete_list(CustomScanState *node) ExprContext *econtext = css->css.ss.ps.ps_ExprContext; TupleTableSlot *scanTupleSlot = econtext->ecxt_scantuple; EState *estate = node->ss.ps.state; + HTAB *qual_cache = NULL; + HASHCTL hashctl; + + /* Hash table for caching compiled security quals per label */ + MemSet(&hashctl, 0, sizeof(hashctl)); + hashctl.keysize = sizeof(Oid); + hashctl.entrysize = sizeof(RLSCacheEntry); + hashctl.hcxt = CurrentMemoryContext; + qual_cache = hash_create("delete_qual_cache", 8, &hashctl, + HASH_ELEM | HASH_BLOBS | HASH_CONTEXT); foreach(lc, css->delete_data->delete_items) { @@ -382,6 +395,7 @@ static void process_delete_list(CustomScanState *node) char *label_name; Integer *pos; int entity_position; + Oid relid; item = lfirst(lc); @@ -400,6 +414,7 @@ static void process_delete_list(CustomScanState *node) label_name = pnstrdup(label->val.string.val, label->val.string.len); resultRelInfo = create_entity_result_rel_info(estate, css->delete_data->graph_name, label_name); + relid = RelationGetRelid(resultRelInfo->ri_RelationDesc); /* * Setup the scan key to require the id field on-disc to match the @@ -447,6 +462,36 @@ static void process_delete_list(CustomScanState *node) continue; } + /* Check RLS security quals (USING policy) before delete */ + if (check_enable_rls(relid, InvalidOid, true) == RLS_ENABLED) + { + RLSCacheEntry *entry; + bool found; + + /* Get cached security quals and slot for this label */ + entry = hash_search(qual_cache, &relid, HASH_ENTER, &found); + if (!found) + { + entry->qualExprs = setup_security_quals(resultRelInfo, estate, + node, CMD_DELETE); + entry->slot = ExecInitExtraTupleSlot( + estate, RelationGetDescr(resultRelInfo->ri_RelationDesc), + &TTSOpsHeapTuple); + entry->withCheckOptions = NIL; + entry->withCheckOptionExprs = NIL; + } + + ExecStoreHeapTuple(heap_tuple, entry->slot, false); + + /* Silently skip if USING policy filters out this row */ + if (!check_security_quals(entry->qualExprs, entry->slot, econtext)) + { + table_endscan(scan_desc); + destroy_entity_result_rel_info(resultRelInfo); + continue; + } + } + /* * For vertices, we insert the vertex ID in the hashtable * vertex_id_htab. This hashtable is used later to process @@ -466,6 +511,9 @@ static void process_delete_list(CustomScanState *node) table_endscan(scan_desc); destroy_entity_result_rel_info(resultRelInfo); } + + /* Clean up the cache */ + hash_destroy(qual_cache); } /* @@ -489,9 +537,14 @@ static void check_for_connected_edges(CustomScanState *node) TableScanDesc scan_desc; HeapTuple tuple; TupleTableSlot *slot; + Oid relid; + bool rls_enabled = false; + List *qualExprs = NIL; + ExprContext *econtext = NULL; resultRelInfo = create_entity_result_rel_info(estate, graph_name, label_name); + relid = RelationGetRelid(resultRelInfo->ri_RelationDesc); estate->es_snapshot->curcid = GetCurrentCommandId(false); estate->es_output_cid = GetCurrentCommandId(false); scan_desc = table_beginscan(resultRelInfo->ri_RelationDesc, @@ -500,6 +553,22 @@ static void check_for_connected_edges(CustomScanState *node) estate, RelationGetDescr(resultRelInfo->ri_RelationDesc), &TTSOpsHeapTuple); + /* + * For DETACH DELETE with RLS enabled, compile the security qual + * expressions once per label for efficient evaluation. + */ + if (css->delete_data->detach) + { + /* Setup RLS security quals for this label */ + if (check_enable_rls(relid, InvalidOid, true) == RLS_ENABLED) + { + rls_enabled = true; + econtext = css->css.ss.ps.ps_ExprContext; + qualExprs = setup_security_quals(resultRelInfo, estate, node, + CMD_DELETE); + } + } + /* for each row */ while (true) { @@ -537,6 +606,34 @@ static void check_for_connected_edges(CustomScanState *node) { if (css->delete_data->detach) { + AclResult aclresult; + + /* Check that the user has DELETE permission on the edge table */ + aclresult = pg_class_aclcheck(relid, GetUserId(), ACL_DELETE); + if (aclresult != ACLCHECK_OK) + { + aclcheck_error(aclresult, OBJECT_TABLE, label_name); + } + + /* Check RLS security quals (USING policy) before delete */ + if (rls_enabled) + { + /* + * For DETACH DELETE, error out if edge RLS check fails. + * Unlike normal DELETE which silently skips, we cannot + * silently skip edges here as it would leave dangling + * edges pointing to deleted vertices. + */ + if (!check_security_quals(qualExprs, slot, econtext)) + { + ereport(ERROR, + (errcode(ERRCODE_INSUFFICIENT_PRIVILEGE), + errmsg("cannot delete edge due to row-level security policy on \"%s\"", + label_name), + errhint("DETACH DELETE requires permission to delete all connected edges."))); + } + } + delete_entity(estate, resultRelInfo, tuple); } else diff --git a/src/backend/executor/cypher_merge.c b/src/backend/executor/cypher_merge.c index 9136825ab..e0d6c78e8 100644 --- a/src/backend/executor/cypher_merge.c +++ b/src/backend/executor/cypher_merge.c @@ -19,10 +19,12 @@ #include "postgres.h" +#include "utils/datum.h" +#include "utils/rls.h" + #include "catalog/ag_label.h" #include "executor/cypher_executor.h" #include "executor/cypher_utils.h" -#include "utils/datum.h" /* * The following structure is used to hold a single vertex or edge component @@ -180,6 +182,12 @@ static void begin_cypher_merge(CustomScanState *node, EState *estate, cypher_node->prop_expr_state = ExecInitExpr(cypher_node->prop_expr, (PlanState *)node); } + + /* Setup RLS WITH CHECK policies if RLS is enabled */ + if (check_enable_rls(rel->rd_id, InvalidOid, true) == RLS_ENABLED) + { + setup_wcos(cypher_node->resultRelInfo, estate, node, CMD_INSERT); + } } /* diff --git a/src/backend/executor/cypher_set.c b/src/backend/executor/cypher_set.c index d1837fb16..40cf2b232 100644 --- a/src/backend/executor/cypher_set.c +++ b/src/backend/executor/cypher_set.c @@ -19,7 +19,10 @@ #include "postgres.h" +#include "common/hashfn.h" +#include "executor/executor.h" #include "storage/bufmgr.h" +#include "utils/rls.h" #include "executor/cypher_executor.h" #include "executor/cypher_utils.h" @@ -125,6 +128,13 @@ static HeapTuple update_entity_tuple(ResultRelInfo *resultRelInfo, ExecConstraints(resultRelInfo, elemTupleSlot, estate); } + /* Check RLS WITH CHECK policies if configured */ + if (resultRelInfo->ri_WithCheckOptions != NIL) + { + ExecWithCheckOptions(WCO_RLS_UPDATE_CHECK, resultRelInfo, + elemTupleSlot, estate); + } + result = table_tuple_update(resultRelInfo->ri_RelationDesc, &tuple->t_self, elemTupleSlot, cid, estate->es_snapshot, @@ -355,9 +365,20 @@ static void process_update_list(CustomScanState *node) EState *estate = css->css.ss.ps.state; int *luindex = NULL; int lidx = 0; + HTAB *qual_cache = NULL; + HASHCTL hashctl; /* allocate an array to hold the last update index of each 'entity' */ luindex = palloc0(sizeof(int) * scanTupleSlot->tts_nvalid); + + /* Hash table for caching compiled security quals per label */ + MemSet(&hashctl, 0, sizeof(hashctl)); + hashctl.keysize = sizeof(Oid); + hashctl.entrysize = sizeof(RLSCacheEntry); + hashctl.hcxt = CurrentMemoryContext; + qual_cache = hash_create("update_qual_cache", 8, &hashctl, + HASH_ELEM | HASH_BLOBS | HASH_CONTEXT); + /* * Iterate through the SET items list and store the loop index of each * 'entity' update. As there is only one entry for each entity, this will @@ -505,6 +526,38 @@ static void process_update_list(CustomScanState *node) estate, RelationGetDescr(resultRelInfo->ri_RelationDesc), &TTSOpsHeapTuple); + /* Setup RLS policies if RLS is enabled */ + if (check_enable_rls(resultRelInfo->ri_RelationDesc->rd_id, + InvalidOid, true) == RLS_ENABLED) + { + Oid relid = RelationGetRelid(resultRelInfo->ri_RelationDesc); + RLSCacheEntry *entry; + bool found; + + /* Get cached RLS state for this label, or set it up */ + entry = hash_search(qual_cache, &relid, HASH_ENTER, &found); + if (!found) + { + /* Setup WITH CHECK policies */ + setup_wcos(resultRelInfo, estate, node, CMD_UPDATE); + entry->withCheckOptions = resultRelInfo->ri_WithCheckOptions; + entry->withCheckOptionExprs = resultRelInfo->ri_WithCheckOptionExprs; + + /* Setup security quals */ + entry->qualExprs = setup_security_quals(resultRelInfo, estate, + node, CMD_UPDATE); + entry->slot = ExecInitExtraTupleSlot( + estate, RelationGetDescr(resultRelInfo->ri_RelationDesc), + &TTSOpsHeapTuple); + } + else + { + /* Use cached WCOs */ + resultRelInfo->ri_WithCheckOptions = entry->withCheckOptions; + resultRelInfo->ri_WithCheckOptionExprs = entry->withCheckOptionExprs; + } + } + /* * Now that we have the updated properties, create a either a vertex or * edge Datum for the in-memory update, and setup the tupleTableSlot @@ -580,8 +633,36 @@ static void process_update_list(CustomScanState *node) */ if (HeapTupleIsValid(heap_tuple)) { - heap_tuple = update_entity_tuple(resultRelInfo, slot, estate, - heap_tuple); + bool should_update = true; + Oid relid = RelationGetRelid(resultRelInfo->ri_RelationDesc); + + /* Check RLS security quals (USING policy) before update */ + if (check_enable_rls(relid, InvalidOid, true) == RLS_ENABLED) + { + RLSCacheEntry *entry; + + /* Entry was already created earlier when setting up WCOs */ + entry = hash_search(qual_cache, &relid, HASH_FIND, NULL); + if (!entry) + { + ereport(ERROR, + (errcode(ERRCODE_INTERNAL_ERROR), + errmsg("missing RLS cache entry for relation %u", + relid))); + } + + ExecStoreHeapTuple(heap_tuple, entry->slot, false); + should_update = check_security_quals(entry->qualExprs, + entry->slot, + econtext); + } + + /* Silently skip if USING policy filters out this row */ + if (should_update) + { + heap_tuple = update_entity_tuple(resultRelInfo, slot, estate, + heap_tuple); + } } /* close the ScanDescription */ table_endscan(scan_desc); @@ -595,6 +676,10 @@ static void process_update_list(CustomScanState *node) /* increment loop index */ lidx++; } + + /* Clean up the cache */ + hash_destroy(qual_cache); + /* free our lookup array */ pfree_if_not_null(luindex); } diff --git a/src/backend/executor/cypher_utils.c b/src/backend/executor/cypher_utils.c index c8d568831..eff829925 100644 --- a/src/backend/executor/cypher_utils.c +++ b/src/backend/executor/cypher_utils.c @@ -24,14 +24,36 @@ #include "postgres.h" +#include "executor/executor.h" +#include "miscadmin.h" #include "nodes/makefuncs.h" #include "parser/parse_relation.h" +#include "rewrite/rewriteManip.h" +#include "rewrite/rowsecurity.h" +#include "utils/acl.h" +#include "utils/rls.h" #include "catalog/ag_label.h" #include "commands/label_commands.h" #include "executor/cypher_utils.h" #include "utils/ag_cache.h" +/* RLS helper function declarations */ +static void get_policies_for_relation(Relation relation, CmdType cmd, + Oid user_id, List **permissive_policies, + List **restrictive_policies); +static void add_with_check_options(Relation rel, int rt_index, WCOKind kind, + List *permissive_policies, + List *restrictive_policies, + List **withCheckOptions, bool *hasSubLinks, + bool force_using); +static void add_security_quals(int rt_index, List *permissive_policies, + List *restrictive_policies, + List **securityQuals, bool *hasSubLinks); +static void sort_policies_by_name(List *policies); +static int row_security_policy_cmp(const ListCell *a, const ListCell *b); +static bool check_role_for_policy(ArrayType *policy_roles, Oid user_id); + /* * Given the graph name and the label name, create a ResultRelInfo for the table * those two variables represent. Open the Indices too. @@ -255,6 +277,13 @@ HeapTuple insert_entity_tuple_cid(ResultRelInfo *resultRelInfo, ExecConstraints(resultRelInfo, elemTupleSlot, estate); } + /* Check RLS WITH CHECK policies if configured */ + if (resultRelInfo->ri_WithCheckOptions != NIL) + { + ExecWithCheckOptions(WCO_RLS_INSERT_CHECK, resultRelInfo, + elemTupleSlot, estate); + } + /* Insert the tuple normally */ table_tuple_insert(resultRelInfo->ri_RelationDesc, elemTupleSlot, cid, 0, NULL); @@ -268,3 +297,754 @@ HeapTuple insert_entity_tuple_cid(ResultRelInfo *resultRelInfo, return tuple; } + +/* + * setup_wcos + * + * WithCheckOptions are added during the rewrite phase, but since AGE uses + * CMD_SELECT for all queries, WCOs don't get added for CREATE/SET/MERGE + * operations. This function compensates by adding WCOs at execution time. + * + * Based on PostgreSQL's row security implementation in rowsecurity.c + */ +void setup_wcos(ResultRelInfo *resultRelInfo, EState *estate, + CustomScanState *node, CmdType cmd) +{ + List *permissive_policies; + List *restrictive_policies; + List *withCheckOptions = NIL; + List *wcoExprs = NIL; + ListCell *lc; + Relation rel; + Oid user_id; + int rt_index; + WCOKind wco_kind; + bool hasSubLinks = false; + + /* Determine the WCO kind based on command type */ + if (cmd == CMD_INSERT) + { + wco_kind = WCO_RLS_INSERT_CHECK; + } + else if (cmd == CMD_UPDATE) + { + wco_kind = WCO_RLS_UPDATE_CHECK; + } + else + { + ereport(ERROR, + (errcode(ERRCODE_INTERNAL_ERROR), + errmsg_internal("unexpected command type for setup_wcos"))); + } + + rel = resultRelInfo->ri_RelationDesc; + + /* + * Use rt_index=1 since we're evaluating policies against a single relation. + * Policy quals are stored with varno=1, and we set ecxt_scantuple to the + * tuple we want to check, so keeping varno=1 is correct. + */ + rt_index = 1; + user_id = GetUserId(); + + /* Get the policies for the specified command type */ + get_policies_for_relation(rel, cmd, user_id, + &permissive_policies, + &restrictive_policies); + + /* Build WithCheckOptions from the policies */ + add_with_check_options(rel, rt_index, wco_kind, + permissive_policies, + restrictive_policies, + &withCheckOptions, + &hasSubLinks, + false); + + /* Compile the WCO expressions */ + foreach(lc, withCheckOptions) + { + WithCheckOption *wco = lfirst_node(WithCheckOption, lc); + ExprState *wcoExpr; + + /* Ensure qual is a List for ExecInitQual */ + if (!IsA(wco->qual, List)) + { + wco->qual = (Node *) list_make1(wco->qual); + } + + wcoExpr = ExecInitQual((List *) wco->qual, (PlanState *) node); + wcoExprs = lappend(wcoExprs, wcoExpr); + } + + /* Set up the ResultRelInfo with WCOs */ + resultRelInfo->ri_WithCheckOptions = withCheckOptions; + resultRelInfo->ri_WithCheckOptionExprs = wcoExprs; +} + +/* + * get_policies_for_relation + * + * Returns lists of permissive and restrictive policies to be applied to the + * specified relation, based on the command type and role. + * + * This includes any policies added by extensions. + * + * Copied from PostgreSQL's src/backend/rewrite/rowsecurity.c + */ +static void +get_policies_for_relation(Relation relation, CmdType cmd, Oid user_id, + List **permissive_policies, + List **restrictive_policies) +{ + ListCell *item; + + *permissive_policies = NIL; + *restrictive_policies = NIL; + + /* No policies if RLS descriptor is not present */ + if (relation->rd_rsdesc == NULL) + { + return; + } + + /* First find all internal policies for the relation. */ + foreach(item, relation->rd_rsdesc->policies) + { + bool cmd_matches = false; + RowSecurityPolicy *policy = (RowSecurityPolicy *) lfirst(item); + + /* Always add ALL policies, if they exist. */ + if (policy->polcmd == '*') + { + cmd_matches = true; + } + else + { + /* Check whether the policy applies to the specified command type */ + switch (cmd) + { + case CMD_SELECT: + if (policy->polcmd == ACL_SELECT_CHR) + { + cmd_matches = true; + } + break; + case CMD_INSERT: + if (policy->polcmd == ACL_INSERT_CHR) + { + cmd_matches = true; + } + break; + case CMD_UPDATE: + if (policy->polcmd == ACL_UPDATE_CHR) + { + cmd_matches = true; + } + break; + case CMD_DELETE: + if (policy->polcmd == ACL_DELETE_CHR) + { + cmd_matches = true; + } + break; + case CMD_MERGE: + /* + * We do not support a separate policy for MERGE command. + * Instead it derives from the policies defined for other + * commands. + */ + break; + default: + elog(ERROR, "unrecognized policy command type %d", + (int) cmd); + break; + } + } + + /* + * Add this policy to the relevant list of policies if it applies to + * the specified role. + */ + if (cmd_matches && check_role_for_policy(policy->roles, user_id)) + { + if (policy->permissive) + { + *permissive_policies = lappend(*permissive_policies, policy); + } + else + { + *restrictive_policies = lappend(*restrictive_policies, policy); + } + } + } + + /* + * We sort restrictive policies by name so that any WCOs they generate are + * checked in a well-defined order. + */ + sort_policies_by_name(*restrictive_policies); + + /* + * Then add any permissive or restrictive policies defined by extensions. + * These are simply appended to the lists of internal policies, if they + * apply to the specified role. + */ + if (row_security_policy_hook_restrictive) + { + List *hook_policies = + (*row_security_policy_hook_restrictive) (cmd, relation); + + /* + * As with built-in restrictive policies, we sort any hook-provided + * restrictive policies by name also. Note that we also intentionally + * always check all built-in restrictive policies, in name order, + * before checking restrictive policies added by hooks, in name order. + */ + sort_policies_by_name(hook_policies); + + foreach(item, hook_policies) + { + RowSecurityPolicy *policy = (RowSecurityPolicy *) lfirst(item); + + if (check_role_for_policy(policy->roles, user_id)) + { + *restrictive_policies = lappend(*restrictive_policies, policy); + } + } + } + + if (row_security_policy_hook_permissive) + { + List *hook_policies = + (*row_security_policy_hook_permissive) (cmd, relation); + + foreach(item, hook_policies) + { + RowSecurityPolicy *policy = (RowSecurityPolicy *) lfirst(item); + + if (check_role_for_policy(policy->roles, user_id)) + { + *permissive_policies = lappend(*permissive_policies, policy); + } + } + } +} + +/* + * add_with_check_options + * + * Add WithCheckOptions of the specified kind to check that new records + * added by an INSERT or UPDATE are consistent with the specified RLS + * policies. Normally new data must satisfy the WITH CHECK clauses from the + * policies. If a policy has no explicit WITH CHECK clause, its USING clause + * is used instead. In the special case of an UPDATE arising from an + * INSERT ... ON CONFLICT DO UPDATE, existing records are first checked using + * a WCO_RLS_CONFLICT_CHECK WithCheckOption, which always uses the USING + * clauses from RLS policies. + * + * New WCOs are added to withCheckOptions, and hasSubLinks is set to true if + * any of the check clauses added contain sublink subqueries. + * + * Copied from PostgreSQL's src/backend/rewrite/rowsecurity.c + */ +static void +add_with_check_options(Relation rel, + int rt_index, + WCOKind kind, + List *permissive_policies, + List *restrictive_policies, + List **withCheckOptions, + bool *hasSubLinks, + bool force_using) +{ + ListCell *item; + List *permissive_quals = NIL; + +#define QUAL_FOR_WCO(policy) \ + ( !force_using && \ + (policy)->with_check_qual != NULL ? \ + (policy)->with_check_qual : (policy)->qual ) + + /* + * First collect up the permissive policy clauses, similar to + * add_security_quals. + */ + foreach(item, permissive_policies) + { + RowSecurityPolicy *policy = (RowSecurityPolicy *) lfirst(item); + Expr *qual = QUAL_FOR_WCO(policy); + + if (qual != NULL) + { + permissive_quals = lappend(permissive_quals, copyObject(qual)); + *hasSubLinks |= policy->hassublinks; + } + } + + /* + * There must be at least one permissive qual found or no rows are allowed + * to be added. This is the same as in add_security_quals. + * + * If there are no permissive_quals then we fall through and return a + * single 'false' WCO, preventing all new rows. + */ + if (permissive_quals != NIL) + { + /* + * Add a single WithCheckOption for all the permissive policy clauses, + * combining them together using OR. This check has no policy name, + * since if the check fails it means that no policy granted permission + * to perform the update, rather than any particular policy being + * violated. + */ + WithCheckOption *wco; + + wco = makeNode(WithCheckOption); + wco->kind = kind; + wco->relname = pstrdup(RelationGetRelationName(rel)); + wco->polname = NULL; + wco->cascaded = false; + + if (list_length(permissive_quals) == 1) + { + wco->qual = (Node *) linitial(permissive_quals); + } + else + { + wco->qual = (Node *) makeBoolExpr(OR_EXPR, permissive_quals, -1); + } + + ChangeVarNodes(wco->qual, 1, rt_index, 0); + + *withCheckOptions = list_append_unique(*withCheckOptions, wco); + + /* + * Now add WithCheckOptions for each of the restrictive policy clauses + * (which will be combined together using AND). We use a separate + * WithCheckOption for each restrictive policy to allow the policy + * name to be included in error reports if the policy is violated. + */ + foreach(item, restrictive_policies) + { + RowSecurityPolicy *policy = (RowSecurityPolicy *) lfirst(item); + Expr *qual = QUAL_FOR_WCO(policy); + + if (qual != NULL) + { + qual = copyObject(qual); + ChangeVarNodes((Node *) qual, 1, rt_index, 0); + + wco = makeNode(WithCheckOption); + wco->kind = kind; + wco->relname = pstrdup(RelationGetRelationName(rel)); + wco->polname = pstrdup(policy->policy_name); + wco->qual = (Node *) qual; + wco->cascaded = false; + + *withCheckOptions = list_append_unique(*withCheckOptions, wco); + *hasSubLinks |= policy->hassublinks; + } + } + } + else + { + /* + * If there were no policy clauses to check new data, add a single + * always-false WCO (a default-deny policy). + */ + WithCheckOption *wco; + + wco = makeNode(WithCheckOption); + wco->kind = kind; + wco->relname = pstrdup(RelationGetRelationName(rel)); + wco->polname = NULL; + wco->qual = (Node *) makeConst(BOOLOID, -1, InvalidOid, + sizeof(bool), BoolGetDatum(false), + false, true); + wco->cascaded = false; + + *withCheckOptions = lappend(*withCheckOptions, wco); + } +} + +/* + * sort_policies_by_name + * + * This is only used for restrictive policies, ensuring that any + * WithCheckOptions they generate are applied in a well-defined order. + * This is not necessary for permissive policies, since they are all combined + * together using OR into a single WithCheckOption check. + * + * Copied from PostgreSQL's src/backend/rewrite/rowsecurity.c + */ +static void +sort_policies_by_name(List *policies) +{ + list_sort(policies, row_security_policy_cmp); +} + +/* + * list_sort comparator to sort RowSecurityPolicy entries by name + * + * Copied from PostgreSQL's src/backend/rewrite/rowsecurity.c + */ +static int +row_security_policy_cmp(const ListCell *a, const ListCell *b) +{ + const RowSecurityPolicy *pa = (const RowSecurityPolicy *) lfirst(a); + const RowSecurityPolicy *pb = (const RowSecurityPolicy *) lfirst(b); + + /* Guard against NULL policy names from extensions */ + if (pa->policy_name == NULL) + { + return pb->policy_name == NULL ? 0 : 1; + } + if (pb->policy_name == NULL) + { + return -1; + } + + return strcmp(pa->policy_name, pb->policy_name); +} + +/* + * check_role_for_policy - + * determines if the policy should be applied for the current role + * + * Copied from PostgreSQL's src/backend/rewrite/rowsecurity.c + */ +static bool +check_role_for_policy(ArrayType *policy_roles, Oid user_id) +{ + int i; + Oid *roles = (Oid *) ARR_DATA_PTR(policy_roles); + + /* Quick fall-thru for policies applied to all roles */ + if (roles[0] == ACL_ID_PUBLIC) + { + return true; + } + + for (i = 0; i < ARR_DIMS(policy_roles)[0]; i++) + { + if (has_privs_of_role(user_id, roles[i])) + { + return true; + } + } + + return false; +} + +/* + * add_security_quals + * + * Add security quals to enforce the specified RLS policies, restricting + * access to existing data in a table. If there are no policies controlling + * access to the table, then all access is prohibited --- i.e., an implicit + * default-deny policy is used. + * + * New security quals are added to securityQuals, and hasSubLinks is set to + * true if any of the quals added contain sublink subqueries. + * + * Copied from PostgreSQL's src/backend/rewrite/rowsecurity.c + */ +static void +add_security_quals(int rt_index, + List *permissive_policies, + List *restrictive_policies, + List **securityQuals, + bool *hasSubLinks) +{ + ListCell *item; + List *permissive_quals = NIL; + Expr *rowsec_expr; + + /* + * First collect up the permissive quals. If we do not find any + * permissive policies then no rows are visible (this is handled below). + */ + foreach(item, permissive_policies) + { + RowSecurityPolicy *policy = (RowSecurityPolicy *) lfirst(item); + + if (policy->qual != NULL) + { + permissive_quals = lappend(permissive_quals, + copyObject(policy->qual)); + *hasSubLinks |= policy->hassublinks; + } + } + + /* + * We must have permissive quals, always, or no rows are visible. + * + * If we do not, then we simply return a single 'false' qual which results + * in no rows being visible. + */ + if (permissive_quals != NIL) + { + /* + * We now know that permissive policies exist, so we can now add + * security quals based on the USING clauses from the restrictive + * policies. Since these need to be combined together using AND, we + * can just add them one at a time. + */ + foreach(item, restrictive_policies) + { + RowSecurityPolicy *policy = (RowSecurityPolicy *) lfirst(item); + Expr *qual; + + if (policy->qual != NULL) + { + qual = copyObject(policy->qual); + ChangeVarNodes((Node *) qual, 1, rt_index, 0); + + *securityQuals = list_append_unique(*securityQuals, qual); + *hasSubLinks |= policy->hassublinks; + } + } + + /* + * Then add a single security qual combining together the USING + * clauses from all the permissive policies using OR. + */ + if (list_length(permissive_quals) == 1) + { + rowsec_expr = (Expr *) linitial(permissive_quals); + } + else + { + rowsec_expr = makeBoolExpr(OR_EXPR, permissive_quals, -1); + } + + ChangeVarNodes((Node *) rowsec_expr, 1, rt_index, 0); + *securityQuals = list_append_unique(*securityQuals, rowsec_expr); + } + else + { + /* + * A permissive policy must exist for rows to be visible at all. + * Therefore, if there were no permissive policies found, return a + * single always-false clause. + */ + *securityQuals = lappend(*securityQuals, + makeConst(BOOLOID, -1, InvalidOid, + sizeof(bool), BoolGetDatum(false), + false, true)); + } +} + +/* + * setup_security_quals + * + * Security quals (USING policies) are added during the rewrite phase, but + * since AGE uses CMD_SELECT for all queries, they don't get added for + * UPDATE/DELETE operations. This function sets up security quals at + * execution time to be evaluated against each tuple before modification. + * + * Returns a list of compiled ExprState for the security quals. + */ +List * +setup_security_quals(ResultRelInfo *resultRelInfo, EState *estate, + CustomScanState *node, CmdType cmd) +{ + List *permissive_policies; + List *restrictive_policies; + List *securityQuals = NIL; + List *qualExprs = NIL; + ListCell *lc; + Relation rel; + Oid user_id; + int rt_index; + bool hasSubLinks = false; + + /* Only UPDATE and DELETE have security quals */ + if (cmd != CMD_UPDATE && cmd != CMD_DELETE) + { + ereport(ERROR, + (errcode(ERRCODE_INTERNAL_ERROR), + errmsg_internal("unexpected command type for setup_security_quals"))); + } + + rel = resultRelInfo->ri_RelationDesc; + + /* If no RLS policies exist, return empty list */ + if (rel->rd_rsdesc == NULL) + { + return NIL; + } + + /* + * Use rt_index=1 since we're evaluating policies against a single relation. + * Policy quals are stored with varno=1, and we set ecxt_scantuple to the + * tuple we want to check, so keeping varno=1 is correct. + */ + rt_index = 1; + user_id = GetUserId(); + + /* Get the policies for the specified command type */ + get_policies_for_relation(rel, cmd, user_id, + &permissive_policies, + &restrictive_policies); + + /* Build security quals from the policies */ + add_security_quals(rt_index, permissive_policies, restrictive_policies, + &securityQuals, &hasSubLinks); + + /* Compile the security qual expressions */ + foreach(lc, securityQuals) + { + Expr *qual = (Expr *) lfirst(lc); + ExprState *qualExpr; + + /* Ensure qual is a List for ExecInitQual */ + if (!IsA(qual, List)) + { + qual = (Expr *) list_make1(qual); + } + + qualExpr = ExecInitQual((List *) qual, (PlanState *) node); + qualExprs = lappend(qualExprs, qualExpr); + } + + return qualExprs; +} + +/* + * check_security_quals + * + * Evaluate security quals against a tuple. Returns true if all quals pass + * (row can be modified), false if any qual fails (row should be silently + * skipped). + * + * This matches PostgreSQL's behavior where USING expressions for UPDATE/DELETE + * silently filter rows rather than raising errors. + */ +bool +check_security_quals(List *qualExprs, TupleTableSlot *slot, + ExprContext *econtext) +{ + ListCell *lc; + TupleTableSlot *saved_scantuple; + bool result = true; + + if (qualExprs == NIL) + { + return true; + } + + /* Save and set up the scan tuple for expression evaluation */ + saved_scantuple = econtext->ecxt_scantuple; + econtext->ecxt_scantuple = slot; + + foreach(lc, qualExprs) + { + ExprState *qualExpr = (ExprState *) lfirst(lc); + + if (!ExecQual(qualExpr, econtext)) + { + result = false; + break; + } + } + + econtext->ecxt_scantuple = saved_scantuple; + return result; +} + +/* + * check_rls_for_tuple + * + * Check RLS policies for a tuple without needing full executor context. + * Used by standalone functions like startNode()/endNode() that access + * tables directly. + * + * Returns true if the tuple passes RLS checks (or if RLS is not enabled), + * false if the tuple should be filtered out. + */ +bool +check_rls_for_tuple(Relation rel, HeapTuple tuple, CmdType cmd) +{ + List *permissive_policies; + List *restrictive_policies; + List *securityQuals = NIL; + ListCell *lc; + Oid user_id; + bool hasSubLinks = false; + bool result = true; + EState *estate; + ExprContext *econtext; + TupleTableSlot *slot; + + /* If RLS is not enabled, tuple passes */ + if (check_enable_rls(RelationGetRelid(rel), InvalidOid, true) != RLS_ENABLED) + { + return true; + } + + /* If no RLS policies exist on the relation, tuple passes */ + if (rel->rd_rsdesc == NULL) + { + return true; + } + + /* Get the policies for the specified command type */ + user_id = GetUserId(); + get_policies_for_relation(rel, cmd, user_id, + &permissive_policies, + &restrictive_policies); + + /* Build security quals from the policies (use rt_index=1) */ + add_security_quals(1, permissive_policies, restrictive_policies, + &securityQuals, &hasSubLinks); + + /* If no quals, tuple passes */ + if (securityQuals == NIL) + { + return true; + } + + /* Create minimal execution environment */ + estate = CreateExecutorState(); + econtext = CreateExprContext(estate); + + /* Create tuple slot and store the tuple */ + slot = MakeSingleTupleTableSlot(RelationGetDescr(rel), &TTSOpsHeapTuple); + ExecStoreHeapTuple(tuple, slot, false); + econtext->ecxt_scantuple = slot; + + /* Compile and evaluate each qual */ + foreach(lc, securityQuals) + { + Expr *qual = (Expr *) lfirst(lc); + ExprState *qualExpr; + List *qualList; + + /* ExecPrepareQual expects a List */ + if (!IsA(qual, List)) + { + qualList = list_make1(qual); + } + else + { + qualList = (List *) qual; + } + + /* Use ExecPrepareQual for standalone expression evaluation */ + qualExpr = ExecPrepareQual(qualList, estate); + + if (!ExecQual(qualExpr, econtext)) + { + result = false; + break; + } + } + + /* Clean up */ + ExecDropSingleTupleTableSlot(slot); + FreeExprContext(econtext, true); + FreeExecutorState(estate); + + return result; +} diff --git a/src/backend/parser/cypher_clause.c b/src/backend/parser/cypher_clause.c index 515f8c1df..7b636a3d4 100644 --- a/src/backend/parser/cypher_clause.c +++ b/src/backend/parser/cypher_clause.c @@ -346,6 +346,100 @@ static bool isa_special_VLE_case(cypher_path *path); static ParseNamespaceItem *find_pnsi(cypher_parsestate *cpstate, char *varname); static bool has_list_comp_or_subquery(Node *expr, void *context); +/* + * Add required permissions to the RTEPermissionInfo for a relation. + * Recursively searches through RTEs including subqueries. + */ +static bool +add_rte_permissions_recurse(List *rtable, List *rteperminfos, + Oid relid, AclMode permissions) +{ + ListCell *lc; + + /* First check the perminfos at this level */ + foreach(lc, rteperminfos) + { + RTEPermissionInfo *perminfo = lfirst(lc); + + if (perminfo->relid == relid) + { + perminfo->requiredPerms |= permissions; + return true; + } + } + + /* Then recurse into subqueries */ + foreach(lc, rtable) + { + RangeTblEntry *rte = lfirst(lc); + + if (rte->rtekind == RTE_SUBQUERY && rte->subquery != NULL) + { + if (add_rte_permissions_recurse(rte->subquery->rtable, + rte->subquery->rteperminfos, + relid, permissions)) + { + return true; + } + } + } + + return false; +} + +/* + * Add required permissions to the RTEPermissionInfo for a relation. + * Searches through p_rteperminfos and subqueries for a matching relOid + * and adds the specified permissions to requiredPerms. + */ +static void +add_rte_permissions(ParseState *pstate, Oid relid, AclMode permissions) +{ + add_rte_permissions_recurse(pstate->p_rtable, pstate->p_rteperminfos, + relid, permissions); +} + +/* + * Add required permissions to the label table for a given entity variable. + * Looks up the entity by variable name, extracts its label, and adds + * the specified permissions to the corresponding RTEPermissionInfo. + */ +static void +add_entity_permissions(cypher_parsestate *cpstate, char *var_name, + AclMode permissions) +{ + ParseState *pstate = (ParseState *)cpstate; + transform_entity *entity; + char *label = NULL; + Oid relid; + + entity = find_variable(cpstate, var_name); + if (entity == NULL) + { + return; + } + + if (entity->type == ENT_VERTEX) + { + label = entity->entity.node->label; + } + else if (entity->type == ENT_EDGE) + { + label = entity->entity.rel->label; + } + + if (label == NULL) + { + return; + } + + relid = get_label_relation(label, cpstate->graph_oid); + if (OidIsValid(relid)) + { + add_rte_permissions(pstate, relid, permissions); + } +} + /* * transform a cypher_clause */ @@ -1561,6 +1655,9 @@ static List *transform_cypher_delete_item_list(cypher_parsestate *cpstate, parser_errposition(pstate, col->location))); } + /* Add ACL_DELETE permission to the entity's label table */ + add_entity_permissions(cpstate, val->sval, ACL_DELETE); + add_volatile_wrapper_to_target_entry(query->targetList, resno); pos = makeInteger(resno); @@ -1726,6 +1823,9 @@ cypher_update_information *transform_cypher_remove_item_list( parser_errposition(pstate, set_item->location))); } + /* Add ACL_UPDATE permission to the entity's label table */ + add_entity_permissions(cpstate, variable_name, ACL_UPDATE); + add_volatile_wrapper_to_target_entry(query->targetList, item->entity_position); @@ -1903,6 +2003,9 @@ cypher_update_information *transform_cypher_set_item_list( parser_errposition(pstate, set_item->location))); } + /* Add ACL_UPDATE permission to the entity's label table */ + add_entity_permissions(cpstate, variable_name, ACL_UPDATE); + add_volatile_wrapper_to_target_entry(query->targetList, item->entity_position); diff --git a/src/backend/utils/adt/agtype.c b/src/backend/utils/adt/agtype.c index f2458a30b..c552727d8 100644 --- a/src/backend/utils/adt/agtype.c +++ b/src/backend/utils/adt/agtype.c @@ -44,7 +44,10 @@ #include "libpq/pqformat.h" #include "miscadmin.h" #include "parser/parse_coerce.h" +#include "nodes/nodes.h" +#include "utils/acl.h" #include "utils/builtins.h" +#include "executor/cypher_utils.h" #include "utils/float.h" #include "utils/lsyscache.h" #include "utils/snapmgr.h" @@ -5625,15 +5628,24 @@ static Datum get_vertex(const char *graph, const char *vertex_label, HeapTuple tuple; TupleDesc tupdesc; Datum id, properties, result; + AclResult aclresult; /* get the specific graph namespace (schema) */ Oid graph_namespace_oid = get_namespace_oid(graph, false); /* get the specific vertex label table (schema.vertex_label) */ Oid vertex_label_table_oid = get_relname_relid(vertex_label, - graph_namespace_oid); + graph_namespace_oid); /* get the active snapshot */ Snapshot snapshot = GetActiveSnapshot(); + /* check for SELECT permission on the table */ + aclresult = pg_class_aclcheck(vertex_label_table_oid, GetUserId(), + ACL_SELECT); + if (aclresult != ACLCHECK_OK) + { + aclcheck_error(aclresult, OBJECT_TABLE, vertex_label); + } + /* initialize the scan key */ ScanKeyInit(&scan_keys[0], 1, BTEqualStrategyNumber, F_OIDEQ, Int64GetDatum(graphid)); @@ -5646,11 +5658,24 @@ static Datum get_vertex(const char *graph, const char *vertex_label, /* bail if the tuple isn't valid */ if (!HeapTupleIsValid(tuple)) { + table_endscan(scan_desc); + table_close(graph_vertex_label, ShareLock); ereport(ERROR, (errcode(ERRCODE_UNDEFINED_TABLE), errmsg("graphid %lu does not exist", graphid))); } + /* Check RLS policies - error if filtered out */ + if (!check_rls_for_tuple(graph_vertex_label, tuple, CMD_SELECT)) + { + table_endscan(scan_desc); + table_close(graph_vertex_label, ShareLock); + ereport(ERROR, + (errcode(ERRCODE_INSUFFICIENT_PRIVILEGE), + errmsg("access to vertex %lu denied by row-level security policy on \"%s\"", + graphid, vertex_label))); + } + /* get the tupdesc - we don't need to release this one */ tupdesc = RelationGetDescr(graph_vertex_label); /* bail if the number of columns differs */ diff --git a/src/include/executor/cypher_utils.h b/src/include/executor/cypher_utils.h index 0798f153c..fc4067455 100644 --- a/src/include/executor/cypher_utils.h +++ b/src/include/executor/cypher_utils.h @@ -21,6 +21,7 @@ #define AG_CYPHER_UTILS_H #include "access/heapam.h" +#include "nodes/execnodes.h" #include "nodes/cypher_nodes.h" #include "utils/agtype.h" @@ -127,4 +128,25 @@ HeapTuple insert_entity_tuple_cid(ResultRelInfo *resultRelInfo, TupleTableSlot *elemTupleSlot, EState *estate, CommandId cid); +/* RLS support */ +void setup_wcos(ResultRelInfo *resultRelInfo, EState *estate, + CustomScanState *node, CmdType cmd); +List *setup_security_quals(ResultRelInfo *resultRelInfo, EState *estate, + CustomScanState *node, CmdType cmd); +bool check_security_quals(List *qualExprs, TupleTableSlot *slot, + ExprContext *econtext); +bool check_rls_for_tuple(Relation rel, HeapTuple tuple, CmdType cmd); + +/* Hash table entry for caching RLS state per label */ +typedef struct RLSCacheEntry +{ + Oid relid; /* hash key */ + /* Security quals (USING policies) for UPDATE/DELETE */ + List *qualExprs; + TupleTableSlot *slot; /* slot for old tuple (RLS check) */ + /* WCOs - used only in SET */ + List *withCheckOptions; + List *withCheckOptionExprs; +} RLSCacheEntry; + #endif