I've only just started to play around with this, but I think that postgresql recursive queries can be helpful here. For example, here's some SQL that will create a view of the accounts table called accounts_hierarchy that adds two new columns to the end: id_path and depth. The id_path column will contain a dot-separated path from the root to the specific account, and the depth will be the number of levels below the root that the account exists.
create extension ltree;
create view accounts_hierarchy as
with recursive x as (
select accounts.*, cast(id as varchar)::ltree as id_path, 1 as depth
from accounts
where parent_account_id is null
union all
select y.*, ltree_addtext(x.id_path, cast(y.id as varchar)) as id_path, nlevel(x.id_path)+1 as depth
from x, accounts as y
where x.id = y.parent_account_id
)
select * from x;
Now you can query this new accounts_hierarchy view to do things like find all of the sub-accounts that have a depth=2 (all of the accounts that are directly below the root account):
select * from accounts_hierarchy
where depth = 2
and workflow_state='active';
Or you can select all of the sub-accounts under a particular account hierarchy (in my instance, all of the accounts that are underneath account 39 which is directly below the root account):
select * from accounts_hierarchy
where id_path <@ '1.39'
and workflow_state='active';
I'm totally new to postgresql recursive queries and ltree functions; please chime in if you have other/better ideas!
--Colin