|
| 1 | +--! Previous: - |
| 2 | +--! Hash: sha1:de60470eae2711674026eea0ced5e4917011e6ea |
| 3 | +--! Message: schemas-and-timestamp-trigger |
| 4 | + |
| 5 | +--! split: 0001-reset.sql |
| 6 | +/* |
| 7 | + * Graphile Migrate will run our `current/...` migrations in one batch. Since |
| 8 | + * this is our first migration it's defining the entire database, so we first |
| 9 | + * drop anything that may have previously been created |
| 10 | + * (app_public/app_hidden/app_private) so that we can start from scratch. |
| 11 | + */ |
| 12 | + |
| 13 | +DROP SCHEMA IF EXISTS app_public CASCADE; |
| 14 | +DROP SCHEMA IF EXISTS app_hidden CASCADE; |
| 15 | +DROP SCHEMA IF EXISTS app_private CASCADE; |
| 16 | + |
| 17 | +--! split: 0010-public-permissions.sql |
| 18 | +/* |
| 19 | + * The `public` *schema* contains things like PostgreSQL extensions. We |
| 20 | + * deliberately do not install application logic into the public schema |
| 21 | + * (instead storing it to app_public/app_hidden/app_private as appropriate), |
| 22 | + * but none the less we don't want untrusted roles to be able to install or |
| 23 | + * modify things into the public schema. |
| 24 | + * |
| 25 | + * The `public` *role* is automatically inherited by all other roles; we only |
| 26 | + * want specific roles to be able to access our database so we must revoke |
| 27 | + * access to the `public` role. |
| 28 | + */ |
| 29 | + |
| 30 | +REVOKE ALL ON SCHEMA public FROM PUBLIC; |
| 31 | + |
| 32 | +ALTER DEFAULT PRIVILEGES REVOKE ALL ON SEQUENCES FROM PUBLIC; |
| 33 | +ALTER DEFAULT PRIVILEGES REVOKE ALL ON FUNCTIONS FROM PUBLIC; |
| 34 | + |
| 35 | +-- Of course we want our database owner to be able to do anything inside the |
| 36 | +-- database, so we grant access to the `public` schema: |
| 37 | +GRANT ALL ON SCHEMA public TO :DATABASE_OWNER; |
| 38 | + |
| 39 | +--! split: 0020-schemas.sql |
| 40 | +/* |
| 41 | + * Read about our app_public/app_hidden/app_private schemas here: |
| 42 | + * https://www.graphile.org/postgraphile/namespaces/#advice |
| 43 | + * |
| 44 | + * Note this pattern is not required to use PostGraphile, it's merely the |
| 45 | + * preference of the author of this package. |
| 46 | + */ |
| 47 | + |
| 48 | +CREATE SCHEMA app_public; |
| 49 | +CREATE SCHEMA app_hidden; |
| 50 | +CREATE SCHEMA app_private; |
| 51 | + |
| 52 | +-- The 'visitor' role (used by PostGraphile to represent an end user) may |
| 53 | +-- access the public, app_public and app_hidden schemas (but _NOT_ the |
| 54 | +-- app_private schema). |
| 55 | +GRANT USAGE ON SCHEMA public, app_public, app_hidden TO :DATABASE_VISITOR; |
| 56 | + |
| 57 | +-- We want the `visitor` role to be able to insert rows (`serial` data type |
| 58 | +-- creates sequences, so we need to grant access to that). |
| 59 | +ALTER DEFAULT PRIVILEGES IN SCHEMA public, app_public, app_hidden |
| 60 | + GRANT USAGE, SELECT ON SEQUENCES TO :DATABASE_VISITOR; |
| 61 | + |
| 62 | +-- And the `visitor` role should be able to call functions too. |
| 63 | +ALTER DEFAULT PRIVILEGES IN SCHEMA public, app_public, app_hidden |
| 64 | + GRANT EXECUTE ON FUNCTIONS TO :DATABASE_VISITOR; |
| 65 | + |
| 66 | +--! split: 0030-timestamp-trigger.sql |
| 67 | +/* |
| 68 | + * This trigger is used on tables with created_at and updated_at to ensure that |
| 69 | + * these timestamps are kept valid (namely: `created_at` cannot be changed, and |
| 70 | + * `updated_at` must be monotonically increasing). |
| 71 | + */ |
| 72 | +CREATE FUNCTION app_private.tg__timestamps() RETURNS trigger AS |
| 73 | +$$ |
| 74 | +BEGIN |
| 75 | + new.created_at = (CASE WHEN tg_op = 'INSERT' THEN NOW() ELSE old.created_at END); |
| 76 | + new.updated_at = (CASE |
| 77 | + WHEN tg_op = 'UPDATE' AND old.updated_at >= NOW() |
| 78 | + THEN old.updated_at + INTERVAL '1 millisecond' |
| 79 | + ELSE NOW() END); |
| 80 | + RETURN new; |
| 81 | +END; |
| 82 | +$$ LANGUAGE plpgsql VOLATILE SET search_path TO pg_catalog, public, pg_temp; |
| 83 | +COMMENT ON FUNCTION app_private.tg__timestamps() IS |
| 84 | + E'This trigger should be called on all tables with created_at, updated_at - it ensures that they cannot be manipulated and that updated_at will always be larger than the previous updated_at.'; |
0 commit comments