Created
March 28, 2016 19:11
-
-
Save levlaz/0af3425c79f1c99a88da to your computer and use it in GitHub Desktop.
Create Types and Roles If Not Exist in PostgreSQL
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
BEGIN; | |
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 | |
$$; | |
CREATE TABLE IF NOT EXISTS | |
tasks ( | |
id integer PRIMARY KEY, | |
title varchar(200), | |
status task_status NOT NULL DEFAULT 'todo', | |
created_date timestamp | |
); | |
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; | |
COMMIT; |
I would also be interested in the correct syntax to CREATE TYPE IF NOT EXISTS
:)
The current best solution I've found is
do $$
begin
if not exists (select 1 from pg_type where typname = 'name_of_your_type') then
-- create type
end if;
end $$;
DO ' BEGIN
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = ''name_of_your_type'') THEN
CREATE TYPE name_of_your_type AS ENUM (''aaaa'', ''bbbb'', ''cccc'');
END IF;
END ';
In some situation the '
better than $$
, such as the situation in Java
Caused by: org.postgresql.util.PSQLException: Unterminated dollar quote started at position 3 in SQL DO $$...
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment
👍