How to get the number of users, groups, and nested groups in Bitbucket Data Center and Server?

Platform Notice: Data Center Only - This article only applies to Atlassian products on the Data Center platform.

Note that this KB was created for the Data Center version of the product. Data Center KBs for non-Data-Center-specific features may also work for Server versions of the product, however they have not been tested. 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

Summary

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.

PostgreSQL / Oracle

1 2 3 SELECT DISTINCT count(*) AS group_count FROM cwd_group;

MSSQL

1 2 3 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.

PostgreSQL / Oracle

1 2 3 SELECT DISTINCT count(lower_email_address) AS user_count FROM cwd_user;

MSSQL

1 2 3 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.

PostgreSQL

1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 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

Oracle

1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 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;

MSSQL

1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 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

Updated on April 8, 2025

Still need help?

The Atlassian Community is here for you.