How to get the number of users, groups, and nested groups in Bitbucket Data Center and Server?
Platform notice: Server and Data Center only. This article only applies to Atlassian products on the Server and Data Center platforms.
Support for Server* products ended on February 15th 2024. If you are running a Server product, you can visit the Atlassian Server end of support announcement to review your migration options.
*Except Fisheye and Crucible
Purpose
The number of users and groups, and the depth of nested groups can contribute to performance and other stability problems in your instance. However, it can be difficult to find out the exact number of users and groups being synched from your LDAP directory, especially if you have nested groups.
Solution
If you experience problems, or you want to make sure you don't exceed our recommended guardrails, you can use the following queries to check the total number users and groups.
These queries have been tested with PostgreSQL, Oracle 12c, and Microsoft SQL Server 2017.
Get the total number of groups
Use this query to find out the total number of groups in the instance.
SELECT DISTINCT count(*)
AS group_count
FROM cwd_group;
SELECT DISTINCT count(*)
as group_count
FROM [bitbucketschema].cwd_group;
Get the total number of users
Use this query to find out the total number of users in the instance.
SELECT DISTINCT count(lower_email_address)
AS user_count
FROM cwd_user;
SELECT DISTINCT count(lower_email_address)
as user_count
FROM [bitbucketschema].cwd_user;
Get the depth of nested groups
Use this query to find the depth of nested groups in the instance.
with recursive group_hierarchy as (
select
child_id,
parent_id,
parent_name,
1 as depth_of_nested_groups
from
cwd_membership
where
cwd_membership.membership_type = 'GROUP_GROUP'
union all
select
cwd_membership.child_id,
cwd_membership.parent_id,
cwd_membership.parent_name,
depth_of_nested_groups + 1
from
cwd_membership
join group_hierarchy on
group_hierarchy.parent_id = cwd_membership.child_id
where
cwd_membership.membership_type = 'GROUP_GROUP'
)
select
*
from
group_hierarchy
with group_hierarchy(child_id, parent_id, parent_name, depth) as (
select
child_id,
parent_id,
parent_name,
1 as depth
from
cwd_membership
where
cwd_membership.membership_type = 'GROUP_GROUP'
union all
select
cwd_membership.child_id,
cwd_membership.parent_id,
cwd_membership.parent_name,
depth + 1
from
cwd_membership
join group_hierarchy on
group_hierarchy.parent_id = cwd_membership.child_id
where
cwd_membership.membership_type = 'GROUP_GROUP'
)
select
*
from
group_hierarchy;
with group_hierarchy as (
select
child_id,
parent_id,
parent_name,
1 as depth_of_nested_groups
from
cwd_membership
where
cwd_membership.membership_type = 'GROUP_GROUP'
union all
select
cwd_membership.child_id,
cwd_membership.parent_id,
cwd_membership.parent_name,
depth_of_nested_groups + 1
from
cwd_membership
join group_hierarchy on
group_hierarchy.parent_id = cwd_membership.child_id
where
cwd_membership.membership_type = 'GROUP_GROUP'
)
select
*
from
group_hierarchy