PostgreSQL does not support IF NOT EXISTS
for CREATE DATABASE
statement. It is supported only in CREATE SCHEMA
. Moreover CREATE DATABASE
cannot be issued in transaction therefore it cannot be in DO
block with exception catching.
When CREATE SCHEMA IF NOT EXISTS
is issued and schema already exists then notice (not error) with duplicate object information is raised.
To solve these problems you need to use dblink
extension which opens a new connection to database server and execute query without entering into transaction. You can reuse connection parameters with supplying empty string.
Below is PL/pgSQL
code which fully simulates CREATE DATABASE IF NOT EXISTS
with same behavior like in CREATE SCHEMA IF NOT EXISTS
. It calls CREATE DATABASE
via dblink
, catch duplicate_database
exception (which is issued when database already exists) and converts it into notice with propagating errcode
. String message has appended , skipping
in the same way how it does CREATE SCHEMA IF NOT EXISTS
.
CREATE EXTENSION IF NOT EXISTS dblink;
DO $$
BEGIN
PERFORM dblink_exec('', 'CREATE DATABASE testdb');
EXCEPTION WHEN duplicate_database THEN RAISE NOTICE '%, skipping', SQLERRM USING ERRCODE = SQLSTATE;
END
$$;
This solution is without any race condition like in other answers, where database can be created by external process (or other instance of same script) between checking if database exists and its own creation.
Moreover when CREATE DATABASE
fails with other error than database already exists then this error is propagated as error and not silently discarded. There is only catch for duplicate_database
error. So it really behaves as IF NOT EXISTS
should.
You can put this code into own function, call it directly or from transaction. Just rollback (restore dropped database) would not work.
Testing output (called two times via DO and then directly):
$ sudo -u postgres psql
psql (9.6.12)
Type "help" for help.
postgres=# \set ON_ERROR_STOP on
postgres=# \set VERBOSITY verbose
postgres=#
postgres=# CREATE EXTENSION IF NOT EXISTS dblink;
CREATE EXTENSION
postgres=# DO $$
postgres$# BEGIN
postgres$# PERFORM dblink_exec('', 'CREATE DATABASE testdb');
postgres$# EXCEPTION WHEN duplicate_database THEN RAISE NOTICE '%, skipping', SQLERRM USING ERRCODE = SQLSTATE;
postgres$# END
postgres$# $$;
DO
postgres=#
postgres=# CREATE EXTENSION IF NOT EXISTS dblink;
NOTICE: 42710: extension "dblink" already exists, skipping
LOCATION: CreateExtension, extension.c:1539
CREATE EXTENSION
postgres=# DO $$
postgres$# BEGIN
postgres$# PERFORM dblink_exec('', 'CREATE DATABASE testdb');
postgres$# EXCEPTION WHEN duplicate_database THEN RAISE NOTICE '%, skipping', SQLERRM USING ERRCODE = SQLSTATE;
postgres$# END
postgres$# $$;
NOTICE: 42P04: database "testdb" already exists, skipping
LOCATION: exec_stmt_raise, pl_exec.c:3165
DO
postgres=#
postgres=# CREATE DATABASE testdb;
ERROR: 42P04: database "testdb" already exists
LOCATION: createdb, dbcommands.c:467
dblink_connect
. – Thomism