Altering a domain’s NOT NULL
setting
Once a domain is created, Firebird doesn’t allow you to add or remove a NOT NULL
constraint (DROP CONSTRAINT
will only drop a CHECK
).If you want to change a domain-wide NOT NULL
setting, the official procedure is:
-
Create a new domain with the desired characteristics.
-
Switch all the concerned columns over to the new domain.
-
Drop the old domain.
This is fine when it only concerns a few columns, but what if there are dozens or even hundreds?It is possible to change the setting by going directly to the system table.Be aware however that Firebird does not recommend or support this type of operation, nor is it guaranteed to keep working in future versions.That being said, it’s a relatively simple operation and if properly executed it shouldn’t cause you any problems.
So here’s the SQL, but remember: at your own risk!
update rdb$fields
set rdb$null_flag = <value> where rdb$field_name = '<DomainName>'
To make a domain NOT NULL
, <value>
should be 1
.To remove a NOT NULL
constraint, use 0
or NULL
.
Write the domain name in all-caps if it was created case-insensitively;otherwise, match the case exactly.Don’t use double-quotes and don’t include the ‘<>
’.Also note that, even when DDL autocommit is on (which is the default in isql
and many other clients), this statement won’t be autocommitted because technically it’s not DDL.So don’t forget to commit!
If you have set the flag to 1
, a subsequent SHOW DOMAIN
will immediately report the domain as being NOT NULL
.Likewise, SHOW TABLE
will list all columns based on the domain as NOT NULL
.But if those columns already contained NULL
s, a SELECT
still truthfully reports them as such (the result set column is still “described” as nullable) — for now.You won’t be able to get any new NULL
s in the column though.Close all connections and reconnect, and any illegal NULL
s will appear as zeroes (at least in most clients;if this surprises you, read [nullguide-nulls-reported-as-zeroes], earlier in this guide).
If you have changed the flag from 1
to 0
or NULL
— making the domain nullable — SHOW DOMAIN
and SHOW TABLE
will immediately report the domain and “its” columns as nullable.But you still can’t insert NULL
s in the columns, and any present NULL
s are still shown as zeroes (in most clients).Close all connections and reconnect to straighten everything out.
Lastly, please be warned again that this type of fiddling with the system tables is not recommended or supported by Firebird, and not guaranteed to keep working in future versions.If the number of columns based on the domain is limited, it’s better to switch them over to another domain or built-in type and then drop the old domain.