One of the probably lesser known PostgreSQL parameters is check_function_bodies. If you know Oracle, then you for sure faced “invalid objects” a lot. In PostgreSQL, by default, there is nothing like an invalid object. That implies that you can not create a function or procedure which references an object that does not yet exist.

Lets assume you want to create a function like this, but the table “t1” does not exist:

postgres=# create or replace function f1 () returns setof t1 as
$$
select * from t1;
$$ language 'sql';
ERROR:  type "t1" does not exist

PostgreSQL will not create the function as a dependent objects does not exist. Once the table is there the function will be created:

postgres=# create table t1 ( a int );
CREATE TABLE
postgres=# insert into t1 values(1);
INSERT 0 1
postgres=# create or replace function f1 () returns setof t1 as
$$
select * from t1;
$$ language 'sql';
CREATE FUNCTION
postgres=# select * from f1();
a
---
1

The issue with that is, that you need to follow the order in which functions gets created. Especially when you need to load functions for other users that can easily become tricky and time consuming. This is where check_function_bodies helps:

postgres=# set check_function_bodies = false;
SET
postgres=# create or replace function f2 () returns setof t1 as
$$
select * from t2;
$$ language 'sql';
CREATE FUNCTION

The function was created although t2 did not exist. Executing the function right now of course will generate an error:

postgres=# select * from f2();
ERROR:  relation "t2" does not exist
LINE 2: select * from t2;
^
QUERY:
select * from t2;

CONTEXT:  SQL function "f2" during startup

Once the table is there all is fine:

postgres=# create table t2 ( a int );
CREATE TABLE
postgres=# insert into t2 values (2);
INSERT 0 1
postgres=# select * from f2();
a
---
2

This is very helpful when loading objects provided by an external vendor. pg_dump is doing that by default.