Before PostgreSQL 11 there was no possibility to work with procedures in PostgreSQL, only functions have been supported. Since PostgreSQL 11, procedures are supported and many waited for that because procedures also brought transaction control (commit/rollback), which is not possible with functions. Next year, when PostgreSQL 14 will be released there will also be support for OUT parameters. Currently only IN, INOUT and VARIADIC are supported. This makes PostgreSQL’s procedures more compatible to Oracle’s implementation of procedures, so lets have a look.

The only way for returning something from a procedure currently is to use INOUT:

postgres=# select version();
                                                          version                                                          
---------------------------------------------------------------------------------------------------------------------------
 PostgreSQL 13.1 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 8.4.1 20200928 (Red Hat 8.4.1-1), 64-bit
(1 row)

postgres=# create table t1 ( a int, b text);
CREATE TABLE
postgres=# insert into t1 values (1,'aa');
INSERT 0 1
postgres=# create or replace procedure p1 ( p_val inout int )
postgres-# as $$
postgres$# declare
postgres$# begin
postgres$#   select a
postgres$#     into p_val
postgres$#    from t1;
postgres$# end;
postgres$# $$ language plpgsql;
CREATE PROCEDURE

This simple procedure has one INOUT parameter and the parameter will contain the result of the select once the procedure is executed:

postgres=# call p1(5);
 p_val 
-------
     1
(1 row)

You can, of course, use multiple INOUT parameters as well:

postgres=# create or replace procedure p1 ( p_val inout int 
postgres(#                                , p_val2 inout text)
postgres-# as $$
postgres$# declare
postgres$# begin
postgres$#   select a, b
postgres$#     into p_val, p_val2
postgres$#    from t1;
postgres$# end;
postgres$# $$ language plpgsql;
CREATE PROCEDURE
postgres=# call p1 (5,'ccc');
 p_val | p_val2 
-------+--------
     1 | aa
(1 row)

But if you try to use an OUT parameter this will not work:

postgres=# create or replace procedure p1 ( p_val out int )
postgres-# as $$
postgres$# declare
postgres$# begin
postgres$#   select a
postgres$#     into p_val
postgres$#    from t1;
postgres$# end;
postgres$# $$ language plpgsql;
ERROR:  procedures cannot have OUT arguments
HINT:  INOUT arguments are permitted.
postgres=# 

This will change with PostgreSQL 14:

postgres=# select version();
                                                  version                                                  
-----------------------------------------------------------------------------------------------------------
 PostgreSQL 14devel on x86_64-pc-linux-gnu, compiled by gcc (GCC) 8.4.1 20200928 (Red Hat 8.4.1-1), 64-bit
(1 row)

postgres=# create table t1 ( a int, b text );
CREATE TABLE
postgres=# insert into t1 values (1,'aaa');
INSERT 0 1
postgres=# create or replace procedure p1 ( p_val out int )
postgres-# as $$
postgres$# declare
postgres$# begin
postgres$#   select a
postgres$#     into p_val
postgres$#    from t1;
postgres$# end;
postgres$# $$ language plpgsql;
CREATE PROCEDURE

For testing that you somehow need to declare a variable to hold the value, which will be returned:

postgres=# do
postgres-# $$
postgres$# declare 
postgres$#   n int;
postgres$# begin
postgres$#   call p1(n);
postgres$#   raise notice '%', n;
postgres$# end;
postgres$# $$;
NOTICE:  1
DO

Nice.