Is something like this possible?
INSERT INTO Table2 (val)
VALUES ((INSERT INTO Table1 (name) VALUES ('a_title') RETURNING id));
like using the return value as value to insert a row in a second table with a reference to the first table?
You can do so starting with Postgres 9.1:
with rows as (
INSERT INTO Table1 (name) VALUES ('a_title') RETURNING id
)
INSERT INTO Table2 (val)
SELECT id
FROM rows
In the meanwhile, if you're only interested in the id, you can do so with a trigger:
create function t1_ins_into_t2()
returns trigger
as $$
begin
insert into table2 (val) values (new.id);
return new;
end;
$$ language plpgsql;
create trigger t1_ins_into_t2
after insert on table1
for each row
execute procedure t1_ins_into_t2();