Retrieve the details of the pinned comment associated with the issue 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

This article offers a detailed exploration of the process for retrieving information about pinned comments from a database. It includes the necessary queries to effectively access and utilize this data for various internal auditing purpose.

Environment

Jira Data Center

Solution

This was written and tested using a PostgreSQL DB, so you may need to tweak it depending on the database you are using.

There is a dedicated table named "comment_pin" that keeps track of the specific comment IDs which have been pinned within issue comments. By utilizing the query provided below, you can obtain a detailed list of the pinned comments associated with a particular issue key. This list will also include information about the user who pinned each comment, along with the exact timestamp when the comment was pinned.

This query fetches information about all pinned comments that have been added in Jira across all projects.

1 2 3 4 5 6 SELECT (p.pkey||'-'||i.issuenum) AS issuekey,a.actionbody AS "Issue Comment", c.pinned_date AS "Pinned Date",au.lower_user_name AS "User Name" from jiraissue i JOIN project p on i.project=p.id JOIN jiraaction a on a.issueid=i.id JOIN comment_pin c on c.comment_id=a.id JOIN app_user au on au.user_key=c.pinned_by;

To determine the details of pinned comments added for specific projects:

1 2 3 4 5 6 7 SELECT (p.pkey||'-'||i.issuenum) AS issuekey,a.actionbody AS "Issue Comment", c.pinned_date AS "Pinned Date",au.lower_user_name AS "User Name" from jiraissue i JOIN project p on i.project=p.id JOIN jiraaction a on a.issueid=i.id JOIN comment_pin c on c.comment_id=a.id JOIN app_user au on au.user_key=c.pinned_by Where p.pkey='<Project Key>';

Updated on March 24, 2025

Still need help?

The Atlassian Community is here for you.