How to find content by space for a specific string in Confluence

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

To find a specific text string within the Confluence content and spaces, for example a URL, please refer to the following queries:

Solution

  • Query to find only pages with a specific string of text:

1 2 3 4 5 6 7 8 SELECT SP.SPACENAME, SP.SPACEKEY, C.TITLE, C.CONTENTID, C.CONTENTTYPE, C.CONTENT_STATUS, C.PREVVER FROM BODYCONTENT AS BC JOIN CONTENT AS C ON BC.CONTENTID = C.CONTENTID JOIN SPACES AS SP ON C.SPACEID = SP.SPACEID WHERE C.CONTENTTYPE = 'PAGE' AND BC.BODY LIKE '%<string-to-search-for>%' ORDER BY SP.SPACENAME, C.TITLE;

  • Query to find both pages and blogposts with a specific string of text:

1 2 3 4 5 6 7 SELECT SP.SPACENAME, SP.SPACEKEY, C.TITLE, C.CONTENTID, C.CONTENTTYPE, C.CONTENT_STATUS, C.PREVVER FROM BODYCONTENT AS BC JOIN CONTENT AS C ON BC.CONTENTID = C.CONTENTID JOIN SPACES AS SP ON C.SPACEID = SP.SPACEID WHERE BC.BODY LIKE '%<string-to-search-for>%' ORDER BY SP.SPACENAME, C.TITLE;

  • Query to find drafts with a specific string of text:

1 2 3 4 5 6 7 8 SELECT SP.SPACENAME, SP.SPACEKEY, C.TITLE, C.CONTENTID, C.CONTENTTYPE, C.CONTENT_STATUS, C.PREVVER FROM BODYCONTENT AS BC JOIN CONTENT AS C ON BC.CONTENTID = C.CONTENTID JOIN SPACES SP ON SP.SPACEKEY = C.DRAFTSPACEKEY WHERE C.CONTENTTYPE = 'DRAFT' AND BC.BODY LIKE '%<string-to-search-for>%' ORDER BY SP.SPACENAME, C.TITLE;

  • Query to find comments with a specific string of text:

1 2 3 4 5 6 7 8 SELECT C.CONTENTID, C.CONTENTTYPE, C.CONTENT_STATUS, C.PAGEID FROM BODYCONTENT AS BC JOIN CONTENT AS C ON BC.CONTENTID = C.CONTENTID WHERE BC.BODY LIKE '%<string-to-search-for>%' AND C.PREVVER ISNULL AND C.CONTENTTYPE = 'COMMENT' ORDER BY CONTENTID

  • Query to find the page's that contain the comment records extracted from the previous query above:

1 2 3 4 5 6 7 8 9 10 11 12 SELECT SP.SPACENAME, C.CONTENTID, C.TITLE, C.CONTENTTYPE, C.CONTENT_STATUS FROM CONTENT C JOIN SPACES AS SP ON C.SPACEID = SP.SPACEID WHERE C.CONTENTID IN (SELECT C.PAGEID FROM BODYCONTENT AS BC JOIN CONTENT AS C ON BC.CONTENTID = C.CONTENTID WHERE BC.BODY LIKE '%<string-to-search-for>%' AND C.PREVVER ISNULL AND C.CONTENTTYPE = 'COMMENT') ORDER BY SP.SPACENAME, C.TITLE;

⚠️ Please note that these queries may need to be adjusted depending on the database in use.

Updated on April 2, 2025

Still need help?

The Atlassian Community is here for you.