How to create a table only if it does not exist?
Or, how to create any object only if it does not exist.
Or, how to drop any object only if it exists.
This becomes easy using the new EXECUTE STATEMENT feature and some knowlegde of system tables. While you can't write DDL statements in PSQL (stored procedure and trigger bodies), and you can't use IF outside of PSQL, you can use EXECUTE STATEMENT in PSQL. Example:
if (not exists(select 1 from rdb$relations where rdb$relation_name = 'EMPLOYEE')) then
execute statement 'create table employee ( id integer );';
This is fine, but now it seems you need to create a special stored procedure for this. Well, we use another new feature: EXECUTE BLOCK to make it a single statement:
SET TERM !! ;
EXECUTE BLOCK AS BEGIN
if (not exists(select 1 from rdb$relations where rdb$relation_name = 'EMPLOYEE')) then
execute statement 'create table employee ( id integer );';
END!!
SET TERM ; !!
Those SET TERM statements are only needed if you work from an administration tool like isql or FlameRobin. If you run it from your application code, just send the EXECUTE BLOCK block as a single statement.
Similar procedure can be used to drop objects and do various other metadata manipulations from plain SQL.