In this Appendix are topics that developers may wish to refer to, to enhance understanding of features or changes.
In this Appendix are topics that developers may wish to refer to, to enhance understanding of features or changes.
RDB$VALID_BLR
FieldThe field RDB$VALID_BLR
in system tables RDB$PROCEDURES
, RDB$FUNCTIONS
and RDB$TRIGGERS
signal possible invalidation of a PSQL module after alteration of a domain or table column on which the module depends.RDB$VALID_BLR
is set to 0 for any procedure or trigger whose code is made invalid by such a change.
The field RDB$VALID_BODY_FLAG
in RDB$PACKAGES
serves a similar purpose for packages.
In PSQL modules, dependencies arise on the definitions of table columns accessed and also on any parameter or variable that has been defined in the module using the TYPE OF
clause.
After the engine has altered any domain, including the implicit domains created internally behind column definitions and output parameters, the engine internally recompiles all of its dependencies.
Any module that fails to recompile because of an incompatibility arising from a domain change is marked as invalid (“invalidated” by setting the RDB$VALID_BLR
in its system record (in RDB$PROCEDURES
, RDB$FUNCTIONS
or RDB$TRIGGERS
, as appropriate) to zero.
Revalidation (setting RDB$VALID_BLR
to 1) occurs when
the domain is altered again and the new definition is compatible with the previously invalidated module definition, or
the previously invalidated module is altered to match the new domain definition
The following query will find the modules that depend on a specific domain and report the state of their RDB$VALID_BLR
fields:
SELECT * FROM (
SELECT
'Procedure',
rdb$procedure_name,
rdb$valid_blr
FROM rdb$procedures
UNION ALL
SELECT
'Function',
rdb$function_name,
rdb$valid_blr
FROM rdb$functions
UNION ALL
SELECT
'Trigger',
rdb$trigger_name,
rdb$valid_blr
FROM rdb$triggers
) (type, name, valid)
WHERE EXISTS
(SELECT * from rdb$dependencies
WHERE rdb$dependent_name = name
AND rdb$depended_on_name = 'MYDOMAIN')
/* Replace MYDOMAIN with the actual domain name.
Use all-caps if the domain was created
case-insensitively. Otherwise, use the exact
capitalisation. */
The following query will find the modules that depend on a specific table column and report the state of their RDB$VALID_BLR
fields:
SELECT * FROM (
SELECT
'Procedure',
rdb$procedure_name,
rdb$valid_blr
FROM rdb$procedures
UNION ALL
SELECT
'Function',
rdb$function_name,
rdb$valid_blr
FROM rdb$functions
UNION ALL
SELECT
'Trigger',
rdb$trigger_name,
rdb$valid_blr
FROM rdb$triggers) (type, name, valid)
WHERE EXISTS
(SELECT *
FROM rdb$dependencies
WHERE rdb$dependent_name = name
AND rdb$depended_on_name = 'MYTABLE'
AND rdb$field_name = 'MYCOLUMN')
Important
|
All PSQL invalidations caused by domain/column changes are reflected in the
|
Note
|
Other Notes
|
Important
|
This note about equality and inequality operators applies everywhere in Firebird’s SQL language. |
The “=
” operator, which is explicitly used in many conditions, only matches values to values.According to the SQL standard, NULL
is not a value and hence two NULL
s are neither equal nor unequal to one another.If you need NULL
s to match each other in a condition, use the IS NOT DISTINCT FROM
operator.This operator returns true if the operands have the same value or if they are both NULL
.
select *
from A join B
on A.id is not distinct from B.code
Likewise, in cases where you want to test against NULL
for a condition of inequality, use IS DISTINCT FROM
, not “<>
”.If you want NULL
to be considered different from any value and two NULL
s to be considered equal:
select *
from A join B
on A.id is distinct from B.code