Examples of Sub-Procedures
-
Subroutines in
EXECUTE BLOCK
EXECUTE BLOCK RETURNS (name VARCHAR(63)) AS -- Sub-procedure returning a list of tables DECLARE PROCEDURE get_tables RETURNS (table_name VARCHAR(63)) AS BEGIN FOR SELECT RDB$RELATION_NAME FROM RDB$RELATIONS WHERE RDB$VIEW_BLR IS NULL INTO table_name DO SUSPEND; END -- Sub-procedure returning a list of views DECLARE PROCEDURE get_views RETURNS (view_name VARCHAR(63)) AS BEGIN FOR SELECT RDB$RELATION_NAME FROM RDB$RELATIONS WHERE RDB$VIEW_BLR IS NOT NULL INTO view_name DO SUSPEND; END BEGIN FOR SELECT table_name FROM get_tables UNION ALL SELECT view_name FROM get_views INTO name DO SUSPEND; END
-
With forward declaration and parameter with default value
execute block returns (o integer) as -- Forward declaration of P1. declare procedure p1(i integer = 1) returns (o integer); -- Forward declaration of P2. declare procedure p2(i integer) returns (o integer); -- Implementation of P1 should not re-declare parameter default value. declare procedure p1(i integer) returns (o integer) as begin execute procedure p2(i) returning_values o; end declare procedure p2(i integer) returns (o integer) as begin o = i; end begin execute procedure p1 returning_values o; suspend; end