Types and Roles If Not Exists in PostgreSQL

For certain operations such as creating types and roles in PostgreSQL you are not able to use the handy IF NOT EXISTS parameter. This makes creating reusable scripts a bit more challenging, especially if you are going to be running these scripts more than once against the same database.

On solution to this problem is to Just Do It™. DO allows you to execute anonymous code blocks. For example, suppose we had a simple task table with a custom type called task_status along with a reader role that has only select permissions. Using the pg_type and pg_role tables we can write a DO expression that will check to make sure that the elements do not exist before attempting to create them, which will prevent your script from erroring out in the event that they do exist.

First we will create the custom type.

DO $$
BEGIN
    IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'task_status') THEN
        CREATE TYPE task_status AS ENUM ('todo', 'doing', 'blocked', 'done');
    END IF;
END
$$;

Then we can create our table.

CREATE TABLE IF NOT EXISTS
tasks (
  id           integer PRIMARY KEY,
  title        varchar(200), 
  status       task_status NOT NULL DEFAULT 'todo',
  created_date timestamp
);

Next, we can create our new role called reader and grant read only rights on the tasks table.

DO $$
BEGIN
    IF NOT EXISTS (SELECT 1 FROM pg_roles WHERE rolname = 'reader') THEN
        CREATE ROLE reader;
    END IF;
END
$$;
GRANT SELECT ON tasks TO reader;

The entire script is shown below.

You can run this script as many times as you wish and it will just work™, which means that if you are running full migrations then you do not have to do any manual overrides or comment anything out. Note that the reason why we do not have to wrap up the GRANT in a check is because if you duplicate a grant, PostgreSQL will return a notice but not an error.

If you made it this far, you should probably follow me on twitter. 🙂

This entry was posted in Databases and tagged . Bookmark the permalink.

Leave a Reply

Your email address will not be published. Required fields are marked *