How to query (SQL) all custom fields not being used in any screen

I have several custom fields (around 250) and some of them are not being used anymore (but may have some value or not).

JIRA customfield interface is not very good to find inactive custom fields (like it work to find inactive workflows).

 

I would like to query database to list all customfields (id or name) that are not applied in any screens.

After that I will check if the field has some value (JQL) and if it is OK to be deleted (maybe the value was migrated to a new field).

 

 

 

2 answers

I'm not sure for the SQL, but in the JQL, I have used the query below to cleanup my 500+ custom fields before

"Custom Field" is not NULL

The results of this query will be all the issues that have this custom field. If it returned 0 results, then you may 86 that custom field without any worries.

You have to be careful with that, even though the fields maybe empty if you have a workflow that sets the value, then you can break the workflow when it tries to set the customfield you just deleted. I found this out the hard way sad

Have you found a solution? (sql?)

SELECT CF.cfname, count(CV.ISSUE) FROM customfield CF join customfieldvalue CV on CF.ID = CV.CUSTOMFIELD
group by CF.cfname

That tells you fields used on issues, but not whether a field is in use on a screen (or in other places like workflows)

Here's some more SQL I run to check for use of customfields

Dashboard gadgets

SELECT *
FROM
    gadgetuserpreference
INNER JOIN portletconfiguration ON portletconfiguration.id = gadgetuserpreference.portletconfiguration
INNER JOIN portalpage ON portalpage.id = portletconfiguration.portalpage
WHERE
    userprefvalue LIKE '%12340'

Filters

select * from searchrequest s where s.reqcontent like '%MyCFName%' or s.reqcontent like '%cf[12940]%'

Screens

SELECT cf.id, fsli.fieldidentifier, cf.cfname, fs.name, fst.name FROM fieldscreenlayoutitem fsli
INNER JOIN fieldscreentab fst
ON fsli.fieldscreentab = fst.id
INNER JOIN fieldscreen fs
ON fst.fieldscreen = fs.id
INNER JOIN customfield cf
ON fsli.fieldidentifier = 'customfield_' || cf.id::text
WHERE fsli.fieldidentifier LIKE '%customfield_10009%'

Workflows

select * from jiraworkflows wf where wf.descriptor like '%customfield_12940%';

Suggest an answer

Log in or Sign up to answer
Atlassian Community Anniversary

Happy Anniversary, Atlassian Community!

This community is celebrating its one-year anniversary and Atlassian co-founder Mike Cannon-Brookes has all the feels.

Read more
Community showcase
Julia Dillon
Posted Apr 17, 2018 in Jira

Tell us how your team runs on Jira!

Hey Atlassian Community! Today we are launching a bunch of customer stories about the amazing work teams, like Dropbox and Twilio, are doing with Jira. You can check out the stories here. The thi...

764 views 2 19
Join discussion

Atlassian User Groups

Connect with like-minded Atlassian users at free events near you!

Find a group

Connect with like-minded Atlassian users at free events near you!

Find my local user group

Unfortunately there are no AUG chapters near you at the moment.

Start an AUG

You're one step closer to meeting fellow Atlassian users at your local meet up. Learn more about AUGs

Groups near you