84 lines
4.2 KiB
Django/Jinja
84 lines
4.2 KiB
Django/Jinja
-- PostgreSQL Static Roles for {{ service }}
|
|
-- Generated by Ansible - run once per service
|
|
--
|
|
-- Creates:
|
|
-- {{ service }}_owner - Owns database and all objects (NOLOGIN)
|
|
-- {{ service }}_app - DML permissions (SELECT, INSERT, UPDATE, DELETE)
|
|
-- {{ service }}_migrate - DDL+DML permissions (for migrations)
|
|
--
|
|
-- Vault dynamic roles inherit from _app or _migrate
|
|
|
|
-- =============================================================================
|
|
-- 1. Create owner role (NOLOGIN, owns all objects)
|
|
-- =============================================================================
|
|
CREATE ROLE {{ service }}_owner NOLOGIN;
|
|
|
|
-- =============================================================================
|
|
-- 2. Create database owned by the owner role
|
|
-- =============================================================================
|
|
CREATE DATABASE {{ service }} OWNER {{ service }}_owner;
|
|
|
|
-- =============================================================================
|
|
-- 3. Connect to the new database for schema grants
|
|
-- =============================================================================
|
|
\c {{ service }}
|
|
|
|
-- =============================================================================
|
|
-- 4. Create app role template (DML only - SELECT, INSERT, UPDATE, DELETE)
|
|
-- =============================================================================
|
|
CREATE ROLE {{ service }}_app NOLOGIN NOINHERIT;
|
|
|
|
-- Grant DML permissions
|
|
GRANT CONNECT ON DATABASE {{ service }} TO {{ service }}_app;
|
|
GRANT USAGE ON SCHEMA public TO {{ service }}_app;
|
|
GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA public TO {{ service }}_app;
|
|
GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO {{ service }}_app;
|
|
|
|
-- =============================================================================
|
|
-- 5. Create migrate role template (DDL+DML - for migrations)
|
|
-- =============================================================================
|
|
CREATE ROLE {{ service }}_migrate NOLOGIN NOINHERIT;
|
|
|
|
-- Grant all privileges
|
|
GRANT CONNECT ON DATABASE {{ service }} TO {{ service }}_migrate;
|
|
GRANT ALL PRIVILEGES ON SCHEMA public TO {{ service }}_migrate;
|
|
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO {{ service }}_migrate;
|
|
GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA public TO {{ service }}_migrate;
|
|
GRANT ALL PRIVILEGES ON ALL FUNCTIONS IN SCHEMA public TO {{ service }}_migrate;
|
|
|
|
-- =============================================================================
|
|
-- 6. Set default privileges for future objects (CRITICAL)
|
|
-- Ensures new tables created during migrations are accessible
|
|
-- =============================================================================
|
|
|
|
-- Default privileges for objects created by _owner role
|
|
ALTER DEFAULT PRIVILEGES FOR ROLE {{ service }}_owner IN SCHEMA public
|
|
GRANT SELECT, INSERT, UPDATE, DELETE ON TABLES TO {{ service }}_app;
|
|
|
|
ALTER DEFAULT PRIVILEGES FOR ROLE {{ service }}_owner IN SCHEMA public
|
|
GRANT USAGE, SELECT ON SEQUENCES TO {{ service }}_app;
|
|
|
|
ALTER DEFAULT PRIVILEGES FOR ROLE {{ service }}_owner IN SCHEMA public
|
|
GRANT ALL PRIVILEGES ON TABLES TO {{ service }}_migrate;
|
|
|
|
ALTER DEFAULT PRIVILEGES FOR ROLE {{ service }}_owner IN SCHEMA public
|
|
GRANT ALL PRIVILEGES ON SEQUENCES TO {{ service }}_migrate;
|
|
|
|
ALTER DEFAULT PRIVILEGES FOR ROLE {{ service }}_owner IN SCHEMA public
|
|
GRANT ALL PRIVILEGES ON FUNCTIONS TO {{ service }}_migrate;
|
|
|
|
-- Default privileges for objects created by _migrate role
|
|
-- (migrations run as _migrate via SET ROLE, so tables are owned by _migrate)
|
|
ALTER DEFAULT PRIVILEGES FOR ROLE {{ service }}_migrate IN SCHEMA public
|
|
GRANT SELECT, INSERT, UPDATE, DELETE ON TABLES TO {{ service }}_app;
|
|
|
|
ALTER DEFAULT PRIVILEGES FOR ROLE {{ service }}_migrate IN SCHEMA public
|
|
GRANT USAGE, SELECT ON SEQUENCES TO {{ service }}_app;
|
|
|
|
-- =============================================================================
|
|
-- 7. Grant roles to vault_admin (WITH ADMIN OPTION for dynamic role creation)
|
|
-- =============================================================================
|
|
GRANT {{ service }}_app TO vault_admin WITH ADMIN OPTION;
|
|
GRANT {{ service }}_migrate TO vault_admin WITH ADMIN OPTION;
|
|
GRANT {{ service }}_owner TO vault_admin; -- For REASSIGN OWNED during revocation
|