How to get record count for all tables?
Sometimes, when inspecting a database, you might want to get a quick glance over all the tables to see which ones actually have some data in them. There is no quick and easy way to get rough estimates, but you can always run brute-force "select count(*)" query on each table. Combining EXECUTE STATEMENT and EXECUTE BLOCK you can do this in a single SQL command:
set term !! ;
EXECUTE BLOCK
returns ( stm varchar(60), cnt integer )
as
BEGIN
for select cast('select count(*) from "'||trim(r.RDB$RELATION_NAME)||'"' as varchar(60))
from RDB$RELATIONS r
where (r.RDB$SYSTEM_FLAG is null or r.RDB$SYSTEM_FLAG = 0) and r.RDB$VIEW_BLR is null
order by 1
into :stm
DO
BEGIN
execute statement :stm into :cnt;
suspend;
END
END
If you use older version of Firebird that does not support EXECUTE STATEMENT or EXECUTE BLOCK, you can do it via 2-step process. First, SELECT from rdb$relations to get a list of select statements:
select 'select '''||trim(r.RDB$RELATION_NAME)||''', count(*) from "'||trim(r.RDB$RELATION_NAME)||'" union '
from RDB$RELATIONS r
where (r.RDB$SYSTEM_FLAG is null or r.RDB$SYSTEM_FLAG = 0)
and r.RDB$VIEW_BLR is null
order by 1
and then copy/paste the resulting statement and execute it in isql or your favorite administration tool (for example, FlameRobin). Make sure you remove the final "union" at the end.