diff --git a/db/README.md b/db/README.md index 25df0da61..d59715c5b 100644 --- a/db/README.md +++ b/db/README.md @@ -3,6 +3,23 @@ This project contains Nomulus's Cloud SQL schema and schema-deployment utilities. +### Database Roles and Privileges + +Nomulus uses the 'postgres' database in the 'public' schema. The following +users/roles are defined: + +* postgres: the initial user is used for admin and schema deployment. + * In Cloud SQL, we do not control superusers. The initial 'postgres' user + is a regular user with create-role/create-db privileges. Therefore, + it is not possible to separate admin user and schema-deployment user. +* readwrite is a role with read-write privileges on all data tables and + sequences. However, it does not have write access to admin tables. Nor + can it create new tables. + * The Registry server user is granted this role. +* readonly is a role with SELECT privileges on all tables. + * Reporting job user and individual human readers may be granted + this role. + ### Schema DDL Scripts Currently we use Flyway for schema deployment. Versioned incremental update diff --git a/db/src/main/resources/sql/user/create_readonly_user.sql b/db/src/main/resources/sql/user/create_readonly_user.sql index 2b5d6b9c2..54d100650 100644 --- a/db/src/main/resources/sql/user/create_readonly_user.sql +++ b/db/src/main/resources/sql/user/create_readonly_user.sql @@ -12,10 +12,12 @@ -- See the License for the specific language governing permissions and -- limitations under the License. -- --- Script to create a user with read-only permission to all tables. +-- Script to create a user with read-only permission to all tables. The +-- initialize_roles.sql script creates the readonly role used here. +-- Comment out line below if user already exists: CREATE USER :username ENCRYPTED PASSWORD :'password'; -GRANT CONNECT ON DATABASE postgres TO :username; -GRANT USAGE ON SCHEMA public TO :username; -GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO :username; -GRANT SELECT ON ALL TABLES IN SCHEMA public TO :username; +-- Comment out line above and uncomment line below if user has been created +-- from Cloud Dashboard: +-- ALTER USER :username NOCREATEDB NOCREATEROLE; +GRANT readonly TO :username; diff --git a/db/src/main/resources/sql/user/create_readwrite_user.sql b/db/src/main/resources/sql/user/create_readwrite_user.sql index ce5b78b54..b76f79f83 100644 --- a/db/src/main/resources/sql/user/create_readwrite_user.sql +++ b/db/src/main/resources/sql/user/create_readwrite_user.sql @@ -13,11 +13,12 @@ -- limitations under the License. -- -- Script to create a user with read-write permission to all tables (except for --- WRITE permissions to flyway_schema_history). +-- WRITE permissions to flyway_schema_history). The initialize_roles.sql script +-- creates the readwrite role used here. +-- Comment out line below if user already exists: CREATE USER :username ENCRYPTED PASSWORD :'password'; -GRANT CONNECT ON DATABASE postgres TO :username; -GRANT USAGE ON SCHEMA public TO :username; -GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO :username; -GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA public TO :username; -REVOKE INSERT, UPDATE, DELETE ON TABLE public.flyway_schema_history FROM :username; +-- Comment out line above and uncomment line below if user has been created +-- from Cloud Dashboard: +-- ALTER USER :username NOCREATEDB NOCREATEROLE; +GRANT readwrite TO :username; diff --git a/db/src/main/resources/sql/user/delete_user.sql b/db/src/main/resources/sql/user/delete_user.sql index 336c91326..b69d9272c 100644 --- a/db/src/main/resources/sql/user/delete_user.sql +++ b/db/src/main/resources/sql/user/delete_user.sql @@ -14,9 +14,7 @@ -- -- Script to delete a user from the database. -REVOKE ALL PRIVILEGES ON DATABASE postgres FROM :username; -REVOKE ALL PRIVILEGES ON SCHEMA public FROM :username; -REVOKE ALL PRIVILEGES ON ALL TABLES IN SCHEMA public FROM :username; -REVOKE ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA public FROM :username; -REVOKE ALL PRIVILEGES ON ALL FUNCTIONS IN SCHEMA public FROM :username; +-- Ignore warnings like :username is not a member of role readonly/write. +REVOKE readonly FROM :username; +REVOKE readwrite FROM :username; DROP USER :username; diff --git a/db/src/main/resources/sql/user/initialize_roles.sql b/db/src/main/resources/sql/user/initialize_roles.sql new file mode 100644 index 000000000..0c5b9c675 --- /dev/null +++ b/db/src/main/resources/sql/user/initialize_roles.sql @@ -0,0 +1,48 @@ +-- Copyright 2019 The Nomulus Authors. All Rights Reserved. +-- +-- Licensed 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. +-- +-- Initializes roles and their privileges in the postgres database in Cloud SQL. +-- This script should run once under the **'postgres'** user before any other +-- roles or users are created. + +# Prevent backdoor grants through the implicit 'public' role. +REVOKE ALL PRIVILEGES ON SCHEMA public from public; + +CREATE ROLE readonly; +GRANT CONNECT ON DATABASE postgres TO readonly; +GRANT USAGE ON SCHEMA public TO readonly; +GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO readonly; +ALTER DEFAULT PRIVILEGES + IN SCHEMA public + FOR USER postgres + GRANT USAGE, SELECT ON SEQUENCES TO readonly; +GRANT SELECT ON ALL TABLES IN SCHEMA public TO readonly; +ALTER DEFAULT PRIVILEGES + IN SCHEMA public + FOR USER postgres + GRANT SELECT ON TABLES TO readonly; + +CREATE ROLE readwrite; +GRANT CONNECT ON DATABASE postgres TO readwrite; +GRANT USAGE ON SCHEMA public TO readwrite; +GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO readwrite; +ALTER DEFAULT PRIVILEGES + IN SCHEMA public + FOR USER postgres + GRANT USAGE, SELECT ON SEQUENCES TO readwrite; +GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA public TO readwrite; +ALTER DEFAULT PRIVILEGES + IN SCHEMA public + FOR USER postgres + GRANT SELECT, INSERT, UPDATE, DELETE ON TABLES TO readwrite; diff --git a/db/src/main/resources/sql/user/create_admin_user.sql b/db/src/main/resources/sql/user/set_flyway_privileges.sql similarity index 61% rename from db/src/main/resources/sql/user/create_admin_user.sql rename to db/src/main/resources/sql/user/set_flyway_privileges.sql index 3980dcbc1..b8d175a9d 100644 --- a/db/src/main/resources/sql/user/create_admin_user.sql +++ b/db/src/main/resources/sql/user/set_flyway_privileges.sql @@ -12,11 +12,9 @@ -- See the License for the specific language governing permissions and -- limitations under the License. -- --- Script to create a user with read-write permission to schema 'public' and --- all tables. +-- Removes write privileges to Flyway admin table from roles. +-- This script is run once under 'postgres' after initialize_roles.sql +-- has been run AND the initial schema deployment by Flyway is done. -CREATE USER :username ENCRYPTED PASSWORD :'password'; -GRANT CONNECT ON DATABASE postgres TO :username; -GRANT ALL PRIVILEGES ON SCHEMA public TO :username; -GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA public TO :username; -GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO :username; +REVOKE INSERT, UPDATE, DELETE ON TABLE public.flyway_schema_history FROM readonly; +REVOKE INSERT, UPDATE, DELETE ON TABLE public.flyway_schema_history FROM readwrite;