How to add a column only if it does not exist in table?
Sometimes you need to run scripts on databases to create some objects. However, it might be the case that such object already exists in the database. Maybe you modified the production database manually at some point and now you are rolling forward the changes from development computer and you have some CREATE or ADD COLUMN statements that fail because object is already there.
For triggers, procedures, views and exceptions you can use CREATE OR ALTER syntax. But what happens when you want to add a column only if it does not already exist in a table.
If you use Firebird 2.0 or above, there is no need to program, you can write SQL script to do the job. You can run IF EXISTS in PSQL combined with EXECUTE STATEMENT to create the object. However, this needs to be wrapped in DDL block to work and this is where EXECUTE BLOCK statement gets in.
Here's an example how to add an integer field named C1 to table T1, if such field does not exist already:
EXECUTE block as
BEGIN
if (not exists(
select 1 from RDB$RELATION_FIELDS rf
where rf.RDB$RELATION_NAME = 'T1' and rf.RDB$FIELD_NAME = 'C1'))
then
execute statement 'ALTER TABLE T1 ADD C1 INTEGER';
END
If you use Firebird 1.5, there is not EXECUTE BLOCK available, but you can put this code into a stored procedure, like this:
create procedure add_column(tab_name varchar(31), col_name varchar(31),
data_type varchar(100))
BEGIN
if (not exists(
select 1 from RDB$RELATION_FIELDS rf
where rf.RDB$RELATION_NAME = :tab_name and rf.RDB$FIELD_NAME = :col_name))
then
execute statement 'ALTER TABLE "'||tab_name||'" ADD "'||:col_name||'" '||:data_type;
END
As data_type parameter you can add NOT NULL, DEFAULT and similar clauses. You could call a procedure like this:
execute procedure add_column('T1', 'C1', 'INTEGER');