From b421be402a788cb1d9cf5b6ed1b7381c7cf457ec Mon Sep 17 00:00:00 2001 From: Muhammad Usama Date: Thu, 5 Sep 2024 15:31:21 +0500 Subject: [PATCH] PG-853: Access control of pg_tde SQL functions Add SQL interfaces for granting and revoking access to key management and viewer functions. This commit introduces four new SQL functions to manage access to key-related functionalities in the `pg_tde` extension: - `tde_grant_key_management_to_role`: Grants execute permissions on key management functions to the specified user or role. - `tde_revoke_key_management_from_role`: Revokes execute permissions on key management functions from the specified user or role. - `tde_grant_key_viewer_to_role`: Grants execute permissions on key viewer functions to the specified user or role. - `tde_revoke_key_viewer_from_role`: Revokes execute permissions on key viewer functions from the specified user or role. Additionally, upon creating the extension, all execute permissions are revoked from the `PUBLIC` role. Therefore, a superuser must explicitly grant the necessary permissions to non-superusers to access these functions after the extension is created. These additions provide a more controlled and secure way to manage permissions for key management and viewer functionalities within the extension. --- meson.build | 3 +- pg_tde--1.0.sql | 175 ++++++++++++++++++++++++++++++ t/007_access_control.pl | 104 ++++++++++++++++++ t/expected/007_access_control.out | 27 +++++ 4 files changed, 308 insertions(+), 1 deletion(-) create mode 100644 t/007_access_control.pl create mode 100644 t/expected/007_access_control.out diff --git a/meson.build b/meson.build index 7dca74f5..60f1074e 100644 --- a/meson.build +++ b/meson.build @@ -112,7 +112,8 @@ tests += { 't/003_remote_config.pl', 't/004_file_config.pl', 't/005_multiple_extensions.pl', - 't/006_remote_vault_config.pl' + 't/006_remote_vault_config.pl', + 't/007_access_control.pl' ], }, } diff --git a/pg_tde--1.0.sql b/pg_tde--1.0.sql index 8046c3e9..afcc296a 100644 --- a/pg_tde--1.0.sql +++ b/pg_tde--1.0.sql @@ -274,3 +274,178 @@ $$; -- Per database extension initialization SELECT pg_tde_extension_initialize(); + +CREATE OR REPLACE FUNCTION tde_grant_execute_privilege_on_function( + target_user_or_role TEXT, + target_function_name TEXT, + target_function_args TEXT +) +RETURNS BOOLEAN AS $$ +DECLARE + grant_query TEXT; +BEGIN + -- Construct the GRANT statement + grant_query := format('GRANT EXECUTE ON FUNCTION %I(%s) TO %I;', + target_function_name, target_function_args, target_user_or_role); + + -- Execute the GRANT statement + EXECUTE grant_query; + -- If execution reaches here, it means the query was successful + RETURN TRUE; + +END; +$$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION tde_revoke_execute_privilege_on_function( + target_user_or_role TEXT, + target_function_name TEXT, + argument_types TEXT +) +RETURNS BOOLEAN AS $$ +DECLARE + revoke_query TEXT; +BEGIN + -- Construct the REVOKE statement + revoke_query := format('REVOKE EXECUTE ON FUNCTION %I(%s) FROM %I;', + target_function_name, argument_types, target_user_or_role); + + -- Execute the REVOKE statement + EXECUTE revoke_query; + + -- If execution reaches here, it means the query was successful + RETURN TRUE; +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION tde_grant_key_management_to_role( + target_user_or_role TEXT) +RETURNS BOOLEAN +LANGUAGE plpgsql +AS $$ +BEGIN + -- Start the transaction block for performing grants + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_file', 'pg_tde_global, varchar, json'); + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_file', 'pg_tde_global, varchar, text'); + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_file', 'varchar, json'); + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_file', 'varchar, text'); + + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_internal', 'varchar, varchar, JSON, BOOLEAN'); + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider', 'varchar, varchar, JSON'); + + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_vault_v2', 'pg_tde_global, varchar, text, text,text,text'); + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_vault_v2', 'pg_tde_global, varchar, JSON, JSON,JSON,JSON'); + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_vault_v2', 'varchar, text, text,text,text'); + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_vault_v2', 'varchar, JSON, JSON,JSON,JSON'); + + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_set_principal_key', 'varchar, varchar, BOOLEAN'); + + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_rotate_principal_key', 'pg_tde_global, varchar, varchar'); + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_rotate_principal_key', 'varchar, varchar'); + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_rotate_principal_key_internal', 'varchar, varchar, BOOLEAN, BOOLEAN'); + + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_list_all_key_providers', 'OUT INT, OUT varchar, OUT varchar, OUT JSON'); + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_is_encrypted', 'VARCHAR'); + + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_principal_key_info_internal', 'BOOLEAN'); + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_principal_key_info', ''); + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_principal_key_info', 'pg_tde_global'); + -- If all statements succeed, return TRUE + RETURN TRUE; + +EXCEPTION + -- If any error occurs, re-raise the error to roll back the transaction + WHEN OTHERS THEN + RAISE; +END; +$$; + +CREATE OR REPLACE FUNCTION tde_grant_key_viewer_to_role( + target_user_or_role TEXT) +RETURNS BOOLEAN +LANGUAGE plpgsql +AS $$ +BEGIN + -- Start the transaction block for performing grants + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_list_all_key_providers', 'OUT INT, OUT varchar, OUT varchar, OUT JSON'); + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_is_encrypted', 'VARCHAR'); + + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_principal_key_info_internal', 'BOOLEAN'); + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_principal_key_info', ''); + PERFORM tde_grant_execute_privilege_on_function(target_user_or_role, 'pg_tde_principal_key_info', 'pg_tde_global'); + -- If all statements succeed, return TRUE + RETURN TRUE; + +EXCEPTION + -- If any error occurs, re-raise the error to roll back the transaction + WHEN OTHERS THEN + RAISE; +END; +$$; + + + +CREATE OR REPLACE FUNCTION tde_revoke_key_management_from_role( + target_user_or_role TEXT) +RETURNS BOOLEAN +LANGUAGE plpgsql +AS $$ +BEGIN + -- Start the transaction block for performing grants + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_file', 'pg_tde_global, varchar, json'); + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_file', 'pg_tde_global, varchar, text'); + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_file', 'varchar, json'); + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_file', 'varchar, text'); + + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_internal', 'varchar, varchar, JSON, BOOLEAN'); + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider', 'varchar, varchar, JSON'); + + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_vault_v2', 'pg_tde_global, varchar, text, text,text,text'); + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_vault_v2', 'pg_tde_global, varchar, JSON, JSON,JSON,JSON'); + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_vault_v2', 'varchar, text, text,text,text'); + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_add_key_provider_vault_v2', 'varchar, JSON, JSON,JSON,JSON'); + + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_set_principal_key', 'varchar, varchar, BOOLEAN'); + + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_rotate_principal_key', 'pg_tde_global, varchar, varchar'); + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_rotate_principal_key', 'varchar, varchar'); + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_rotate_principal_key_internal', 'varchar, varchar, BOOLEAN, BOOLEAN'); + + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'tde_grant_key_management_to_role', 'TEXT'); + + -- If all statements succeed, return TRUE + RETURN TRUE; + +EXCEPTION + -- If any error occurs, re-raise the error to roll back the transaction + WHEN OTHERS THEN + RAISE; +END; +$$; + +CREATE OR REPLACE FUNCTION tde_revoke_key_viewer_from_role( + target_user_or_role TEXT) +RETURNS BOOLEAN +LANGUAGE plpgsql +AS $$ +BEGIN + -- Start the transaction block for performing grants + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_list_all_key_providers', 'OUT INT, OUT varchar, OUT varchar, OUT JSON'); + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_is_encrypted', 'VARCHAR'); + + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_principal_key_info_internal', 'BOOLEAN'); + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_principal_key_info', ''); + PERFORM tde_revoke_execute_privilege_on_function(target_user_or_role, 'pg_tde_principal_key_info', 'pg_tde_global'); + -- If all statements succeed, return TRUE + RETURN TRUE; + +EXCEPTION + -- If any error occurs, re-raise the error to roll back the transaction + WHEN OTHERS THEN + RAISE; +END; +$$; + +-- Revoking all the privileges from the public role +SELECT tde_revoke_key_management_from_role('public'); +SELECT tde_revoke_key_viewer_from_role('public'); diff --git a/t/007_access_control.pl b/t/007_access_control.pl new file mode 100644 index 00000000..f321cc73 --- /dev/null +++ b/t/007_access_control.pl @@ -0,0 +1,104 @@ +#!/usr/bin/perl + +use strict; +use warnings; +use File::Basename; +use File::Compare; +use File::Copy; +use Test::More; +use lib 't'; +use pgtde; + +# Get file name and CREATE out file name and dirs WHERE requried +PGTDE::setup_files_dir(basename($0)); + +# CREATE new PostgreSQL node and do initdb +my $node = PGTDE->pgtde_init_pg(); +my $pgdata = $node->data_dir; + +# UPDATE postgresql.conf to include/load pg_tde library +open my $conf, '>>', "$pgdata/postgresql.conf"; +print $conf "shared_preload_libraries = 'pg_tde'\n"; +close $conf; + +# Start server +my $rt_value = $node->start; +ok($rt_value == 1, "Start Server"); + +# CREATE EXTENSION and change out file permissions +my ($cmdret, $stdout, $stderr) = $node->psql('postgres', 'CREATE EXTENSION pg_tde;', extra_params => ['-a']); +ok($cmdret == 0, "CREATE PGTDE EXTENSION"); +PGTDE::append_to_file($stdout); + + +($cmdret, $stdout, $stderr) = $node->psql('postgres', 'CREATE USER test_access;', extra_params => ['-a']); +ok($cmdret == 0, "CREATE test_access USER"); +PGTDE::append_to_file($stdout); + +($cmdret, $stdout, $stderr) = $node->psql('postgres', 'grant all ON database postgres TO test_access;', extra_params => ['-a']); +ok($cmdret == 0, "CREATE test_access USER"); +PGTDE::append_to_file($stdout); + +# Restart the server +PGTDE::append_to_file("-- server restart"); +$node->stop(); + +$rt_value = $node->start(); +ok($rt_value == 1, "Restart Server"); + +# TRY performing operations without permission +PGTDE::append_to_file("-- pg_tde_add_key_provider_file should throw access denied"); +($cmdret, $stdout, $stderr) = $node->psql('postgres', "SELECT pg_tde_add_key_provider_file('file-vault','/tmp/pg_tde_test_keyring.per');", extra_params => ['-a', '-U', 'test_access']); +PGTDE::append_to_file($stderr); + +PGTDE::append_to_file("-- pg_tde_set_principal_key should also fail"); +($cmdret, $stdout, $stderr) = $node->psql('postgres', "SELECT pg_tde_set_principal_key('test-db-principal-key','file-vault');", extra_params => ['-a', '-U', 'test_access']); +PGTDE::append_to_file($stderr); + +# now give key management access to test_access user +PGTDE::append_to_file("-- grant key management access to test_access"); +$stdout = $node->safe_psql('postgres', "select tde_grant_key_management_to_role('test_access');", extra_params => ['-a']); +PGTDE::append_to_file($stdout); + +# TRY performing key operation with permission +$stdout = $node->safe_psql('postgres', "SELECT pg_tde_add_key_provider_file('file-vault','/tmp/pg_tde_test_keyring.per');", extra_params => ['-a', '-U', 'test_access']); +PGTDE::append_to_file($cmdret); +PGTDE::append_to_file($stdout); + +$stdout = $node->safe_psql('postgres', "SELECT pg_tde_add_key_provider_file('file-2','/tmp/pg_tde_test_keyring_2.per');", extra_params => ['-a', '-U', 'test_access']); +PGTDE::append_to_file($stdout); + +$stdout = $node->safe_psql('postgres', "SELECT pg_tde_set_principal_key('test-db-principal-key','file-vault');", extra_params => ['-a', '-U', 'test_access']); +PGTDE::append_to_file($stdout); + +$stdout = $node->safe_psql('postgres', "SELECT pg_tde_rotate_principal_key('rotated-principal-key','file-2');", extra_params => ['-a', '-U', 'test_access']); +PGTDE::append_to_file($stdout); + + +$stdout = $node->safe_psql('postgres', 'CREATE SCHEMA test_access;', extra_params => ['-a', '-U', 'test_access']); +PGTDE::append_to_file($stdout); + +$stdout = $node->safe_psql('postgres', 'CREATE TABLE test_access.test_enc1(id SERIAL,k INTEGER,PRIMARY KEY (id)) USING tde_heap_basic;', extra_params => ['-a', '-U', 'test_access']); +PGTDE::append_to_file($stdout); + +$stdout = $node->safe_psql('postgres', 'INSERT INTO test_access.test_enc1 (k) VALUES (5),(6);', extra_params => ['-a', '-U', 'test_access']); +PGTDE::append_to_file($stdout); + +$stdout = $node->safe_psql('postgres', 'SELECT * FROM test_access.test_enc1 ORDER BY id ASC;', extra_params => ['-a', '-U', 'test_access']); +PGTDE::append_to_file($stdout); + +# DROP EXTENSION +$stdout = $node->safe_psql('postgres', 'DROP EXTENSION pg_tde CASCADE;', extra_params => ['-a']); +PGTDE::append_to_file($stdout); + +# Stop the server +$node->stop(); + +# compare the expected and out file +my $compare = PGTDE->compare_results(); + +# Test/check if expected and result/out file match. If Yes, test passes. +is($compare,0,"Compare Files: $PGTDE::expected_filename_with_path and $PGTDE::out_filename_with_path files."); + +# Done testing for this testcase file. +done_testing(); diff --git a/t/expected/007_access_control.out b/t/expected/007_access_control.out new file mode 100644 index 00000000..25bf3e8b --- /dev/null +++ b/t/expected/007_access_control.out @@ -0,0 +1,27 @@ +CREATE EXTENSION pg_tde; +CREATE USER test_access; +grant all ON database postgres TO test_access; +-- server restart +-- pg_tde_add_key_provider_file should throw access denied +psql::1: ERROR: permission denied for function pg_tde_add_key_provider_file +-- pg_tde_set_principal_key should also fail +psql::1: ERROR: permission denied for function pg_tde_set_principal_key +-- grant key management access to test_access +select tde_grant_key_management_to_role('test_access'); +t +3 +SELECT pg_tde_add_key_provider_file('file-vault','/tmp/pg_tde_test_keyring.per'); +1 +SELECT pg_tde_add_key_provider_file('file-2','/tmp/pg_tde_test_keyring_2.per'); +2 +SELECT pg_tde_set_principal_key('test-db-principal-key','file-vault'); +t +SELECT pg_tde_rotate_principal_key('rotated-principal-key','file-2'); +t +CREATE SCHEMA test_access; +CREATE TABLE test_access.test_enc1(id SERIAL,k INTEGER,PRIMARY KEY (id)) USING tde_heap_basic; +INSERT INTO test_access.test_enc1 (k) VALUES (5),(6); +SELECT * FROM test_access.test_enc1 ORDER BY id ASC; +1|5 +2|6 +DROP EXTENSION pg_tde CASCADE;