How to get a list of all Confluence users timezones from the Database
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
For reporting purpose, Confluence administrator might need to retrieve a list of Confluence users' timezone information, it is possible to do so by running the SQL query below against your database.
Solution
This query will give you the user's username and their time zone as defined in their User Profile, if a user has never changed their time zone settings in their profile then there is no information stored in the os_propertyentry table, so we manually added Site Default value to those users in the query below.
MySQL query
1
2
3
4
5
6
7
8
9
10
11
SELECT U.USERNAME,
O.STRING_VAL AS "TIME ZONE"
FROM user_mapping U
INNER JOIN OS_PROPERTYENTRY O ON U.USER_KEY=REPLACE(O.ENTITY_NAME,'USERPROPS-','')
WHERE O.ENTITY_KEY LIKE '%TIME.ZONE%'
UNION ALL
SELECT USERNAME,
'SITE DEFAULT' AS "TIME ZONE"
FROM user_mapping WHERE USER_KEY NOT IN
(SELECT REPLACE(ENTITY_NAME,'USERPROPS-','')
FROM OS_PROPERTYENTRY);
PostgreSQL query
1
2
3
4
5
6
7
8
9
10
11
SELECT u.username,
o.string_val AS "Time zone"
FROM user_mapping u
INNER JOIN os_propertyentry o ON u.user_key=replace(o.entity_name,'USERPROPS-','')
WHERE o.entity_key LIKE '%time.zone%'
UNION ALL
SELECT username,
'Site Default' AS "Time zone"
FROM user_mapping WHERE user_key NOT IN
(SELECT replace(entity_name,'USERPROPS-','')
FROM os_propertyentry);
SQL Server query
1
2
3
4
5
6
7
8
9
10
11
12
SELECT u.username,
o.string_val AS [Time zone]
FROM confluence.dbo.user_mapping u
INNER JOIN confluence.dbo.OS_PROPERTYENTRY o ON u.user_key = replace(o.entity_name, 'USERPROPS-', '')
WHERE o.entity_key LIKE '%time.zone%'
UNION ALL
SELECT username,
'Site Default' AS [Time zone]
FROM confluence.dbo.user_mapping
WHERE user_key NOT IN (
SELECT replace(entity_name, 'USERPROPS-', '')
FROM confluence.dbo.OS_PROPERTYENTRY);
ℹ️ The above queries have been tested in MySQL, PostgreSQL and MS SQL servers and might need syntax changes depending on your database.
Was this helpful?