Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
DanMcG
Regular Visitor

Connect to Jira with Power BI - code for a function

Hi,

 

I recently had to pull some data out of Jira, but couldn't see an easy way to do it natively in Power BI / Power Query, so created a custom function that does it for me based on a JQL statement.

 

Thought it might be useful to others, so have posted below (for my Jira instance this also works with an auto refresh in the service).

 

All you need to do is paste the below code into a blank query, then update the jiraDomain to your domain name.

 

You'll then see a function with 2 parameters, the first wants a JQL statement and the second needs a comma seperated list of the fields that you want from Jira (e.g. "key,Summary,Assignee,Status,Created,Project").

 

To autheniticate, I've been using basic auth with the username as my company email and the password as a Jira API token.

 

 

 

 

let Source = (jql as text, optional columnsToKeep as text) =>
let
    // demo data
    // jql = "project = JSD order by created DESC",
    // columnsToKeep = "key,Summary,Assignee,Status,Created,Project",

    jiraDomain = "https://<your-domain>.atlassian.net",

//get data from Jira using JQL
    getJqlResult = (jql as text)=>
        let
            createQueryTable = Table.FromList(List.Generate(() => 0, each _ < Json.Document(Web.Contents(jiraDomain & "/rest/api/3/search",[RelativePath="?fields=key&jql="&jql]))[total], each _ + 50), Splitter.SplitByNothing(), null, null, ExtraValues.Error),
            addQueries = Table.AddColumn(createQueryTable, "queryLists", each Json.Document(Web.Contents(jiraDomain & "/rest/api/3/search",[RelativePath="?startAt="&Text.From([Column1])&"&jql="&jql]))[issues]),
            removeStartAt = Table.RemoveColumns(addQueries,{"Column1"}),
            expandQueryLists = Table.ExpandListColumn(removeStartAt, "queryLists"),
            expandIssues = Table.ExpandRecordColumn(expandQueryLists, "queryLists", {"id", "key", "fields"}, {"id", "key", "fields"})
        in
            expandIssues,

//get data a list of Jira fields and what the display names are
    getJiraFieldsAndNames = () =>
        let
            jiraFieldNameList = Json.Document(Web.Contents(jiraDomain & "/rest/api/3/field")),
            fieldRecordsToTable = Table.FromList(jiraFieldNameList, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
            expandFieldRecords = Table.ExpandRecordColumn(fieldRecordsToTable, "Column1", {"id", "key", "name"}, {"id", "key", "name"})
        in
            expandFieldRecords,

//create a list of lists that can be used to rename from field system names
    createJiraRenameList = (listOfColumnsToRename as list)=>
        let
            fieldNames = getJiraFieldsAndNames(),
            countNameInstances = Table.AddColumn(fieldNames, "# of Name Columns", each let thisName = [name] in Table.RowCount(Table.SelectRows(fieldNames, each [name] = thisName))),
            checkWhetherFieldRequired = Table.AddColumn(countNameInstances, "renameRequired", each List.Contains(listOfColumnsToRename,[key])),
            filterToRequired = Table.SelectRows(checkWhetherFieldRequired, each ([renameRequired] = true) and ([#"# of Name Columns"] = 1)),
            addRenameListItems = Table.AddColumn(filterToRequired, "renameListItem", each {[key],[name]}),
            createRenameList = Table.Column(addRenameListItems,"renameListItem")
        in
            createRenameList,

//main code

    columnsToKeepAsList = 
        if columnsToKeep = null
        then null
        else Text.Split(Text.Replace(Text.Replace(columnsToKeep," ,",","),", ",","),","),
    
    jqlQueryResult = getJqlResult(jql),
    columnNamesAsList = Table.Column(Record.ToTable(jqlQueryResult{0}[fields]),"Name"),
    expandIssueFields = Table.ExpandRecordColumn(jqlQueryResult, "fields", columnNamesAsList, columnNamesAsList),
    renameColumns = Table.RenameColumns(expandIssueFields,createJiraRenameList(columnNamesAsList)),
    selectColumnsToKeep = 
        if columnsToKeep = null
        then renameColumns
        else Table.SelectColumns(renameColumns,columnsToKeepAsList)
in
    selectColumnsToKeep
in Source

 

 

 

 

1 ACCEPTED SOLUTION
DanMcG
Regular Visitor

Hi,

 

Just made a better one (doesn't pull all fields, so should be much better for bigger queries). For auth follow the same instructions as before.

 

NOTE: with this one, you can also specifiy how many issues is retured in each request (a larger number makes it run faster), but if you're returing a lot of columns Jira may limit this and so you will miss some info. So if you're returning a lot of info and want to make it >50, be careful and do some testing that you're getting all the data you expect (a way to test this is looking at items returned in the query versus what the JQL returns in Jira) - my advice would be to just leave it at 50 😊.

 

 

 

let Source = (optional jql as text, optional fields as text, optional itemsPerQuery as number) =>

let
    // itemsPerQuery = null,//50,
    // jql = null,//"project = ABC",
    // fields = "assignee,key,summary,cReated",

    jiraDomain = "https://<youdomain>.atlassian.net",

    jqlConverted = if jql = null then "" else jql,
    fieldsConverted = if fields = "id" then "key" else fields,
    itemsPerQueryConverted = if itemsPerQuery = null then 50 else Number.Round(itemsPerQuery,0),

    #"(convertFieldsNamesToIds)" = (fieldsToGet as text) =>
        let
            // jiraDomain = "https://rimestechnologies.atlassian.net",
            // fields = "assignee,key,Client Id (global),summary",

            fieldsToGetAsList = Text.Split(Text.Lower(fieldsToGet),","),

            jiraFieldNameList = Json.Document(Web.Contents(jiraDomain & "/rest/api/3/field")),
            fieldRecordsToTable = Table.FromList(jiraFieldNameList, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
            expandFieldRecords = Table.ExpandRecordColumn(fieldRecordsToTable, "Column1", {"id", "key", "name"}, {"id", "key", "name"}),
            addGetFieldCheck = Table.AddColumn(expandFieldRecords, "getField?", each List.Contains(fieldsToGetAsList,Text.Lower([name]))),
            filterToFieldsToGet = Table.SelectRows(addGetFieldCheck, each ([#"getField?"] = true)),
            createFieldsString = Text.Combine(Table.Column(filterToFieldsToGet,"id"),",")
        in
            createFieldsString,

#"(createRenameListFromIds)" = (idsToGetNames as text) =>
    let
        // jiraDomain = "https://rimestechnologies.atlassian.net",
        // idsToGetNames = "summary,customfield_12976,assignee,created",

        idsToGetNamesAsList = Text.Split(Text.Lower(idsToGetNames),","),

        jiraFieldNameList = Json.Document(Web.Contents(jiraDomain & "/rest/api/3/field")),
        fieldRecordsToTable = Table.FromList(jiraFieldNameList, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
        expandFieldRecords = Table.ExpandRecordColumn(fieldRecordsToTable, "Column1", {"id", "key", "name"}, {"id", "key", "name"}),
        addFieldCheck = Table.AddColumn(expandFieldRecords, "getField?", each List.Contains(idsToGetNamesAsList,Text.Lower([id]))),
        filterToFields = Table.SelectRows(addFieldCheck, each ([#"getField?"] = true)),
        addRenameLists = Table.AddColumn(filterToFields, "renameLists", each {[id],[name]}),
        createListOfLists = Table.Column(addRenameLists,"renameLists")
    in
        createListOfLists,

    createQueryTable = 
        Table.FromList(
            List.Generate(
                () => 0, 
                each _ < Json.Document(Web.Contents(jiraDomain & "/rest/api/3/search",
                    [RelativePath=
                        "?fields=key"
                        & "&jql=" & jqlConverted
                    ]))[total], 
                each _ + itemsPerQueryConverted
            )
            , Splitter.SplitByNothing(), null, null, ExtraValues.Error
        ),
    addQueries = Table.AddColumn(createQueryTable, "queryLists", each 
        Json.Document(Web.Contents(
            jiraDomain & "/rest/api/3/search"
            ,[RelativePath=
                "?startAt=" & Text.From([Column1])
                & "&jql=" & jqlConverted
                & "&maxResults=" & Text.From(itemsPerQueryConverted)
                & "&fields=" & Text.From(if fieldsConverted = null then "*all" else #"(convertFieldsNamesToIds)"(fieldsConverted))
            ]
        ))[issues]),
    removeStartAt = Table.RemoveColumns(addQueries,{"Column1"}),
    expandQueryLists = Table.ExpandListColumn(removeStartAt, "queryLists"),
    expandIssues = Table.ExpandRecordColumn(expandQueryLists, "queryLists", {"id", "key", "fields"}, {"id", "key", "fields"}),
    expandFields = 
        if List.First(Table.Column(expandIssues,"fields")) = null
        then expandIssues
        else Table.ExpandRecordColumn(expandIssues, "fields", Record.FieldNames(List.First(Table.Column(expandIssues,"fields"))), Record.FieldNames(List.First(Table.Column(expandIssues,"fields")))),
    renameFields = 
        if List.First(Table.Column(expandIssues,"fields")) = null
        then Table.RemoveColumns(expandFields,{"fields"})
        else Table.RenameColumns(expandFields,#"(createRenameListFromIds)"(Text.Combine(Record.FieldNames(List.First(Table.Column(expandIssues,"fields"))),",")))
in
    renameFields
in Source

 

 

 

 

 

 

View solution in original post

6 REPLIES 6
Anonymous
Not applicable

Hi @DanMcG!

 

Integrating Jira and Power BI can be challenging, but fortunately, you can use two main methods to achieve this. One option is the Jira REST API, which requires technical skills and can be complex. The second option is Power BI Connector for Jira.
It is a user-friendly app that enables you to export Jira data to Power BI without the need for coding skills. Learn more about the second method here: 

https://marketplace.atlassian.com/apps/1221150/power-bi-connector-for-jira?hosting=cloud&tab=overvie... it's available for Jira Cloud / Server / Data Center.

 We have a fast/responsive support team at support@alpha-serve.com . Please let us know if you need any assistance.

Aryna
Helper V
Helper V

Hi @DanMcG , thank you for your post. I just found another solution that might be helpful. This is 

script that integrates Power Bi into Jira: https://vidi-corp.com/how-to-connect-jira-to-power-bi/

This way you pay once and never have to worry about the subscription

DanMcG
Regular Visitor

Hi,

 

Just made a better one (doesn't pull all fields, so should be much better for bigger queries). For auth follow the same instructions as before.

 

NOTE: with this one, you can also specifiy how many issues is retured in each request (a larger number makes it run faster), but if you're returing a lot of columns Jira may limit this and so you will miss some info. So if you're returning a lot of info and want to make it >50, be careful and do some testing that you're getting all the data you expect (a way to test this is looking at items returned in the query versus what the JQL returns in Jira) - my advice would be to just leave it at 50 😊.

 

 

 

let Source = (optional jql as text, optional fields as text, optional itemsPerQuery as number) =>

let
    // itemsPerQuery = null,//50,
    // jql = null,//"project = ABC",
    // fields = "assignee,key,summary,cReated",

    jiraDomain = "https://<youdomain>.atlassian.net",

    jqlConverted = if jql = null then "" else jql,
    fieldsConverted = if fields = "id" then "key" else fields,
    itemsPerQueryConverted = if itemsPerQuery = null then 50 else Number.Round(itemsPerQuery,0),

    #"(convertFieldsNamesToIds)" = (fieldsToGet as text) =>
        let
            // jiraDomain = "https://rimestechnologies.atlassian.net",
            // fields = "assignee,key,Client Id (global),summary",

            fieldsToGetAsList = Text.Split(Text.Lower(fieldsToGet),","),

            jiraFieldNameList = Json.Document(Web.Contents(jiraDomain & "/rest/api/3/field")),
            fieldRecordsToTable = Table.FromList(jiraFieldNameList, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
            expandFieldRecords = Table.ExpandRecordColumn(fieldRecordsToTable, "Column1", {"id", "key", "name"}, {"id", "key", "name"}),
            addGetFieldCheck = Table.AddColumn(expandFieldRecords, "getField?", each List.Contains(fieldsToGetAsList,Text.Lower([name]))),
            filterToFieldsToGet = Table.SelectRows(addGetFieldCheck, each ([#"getField?"] = true)),
            createFieldsString = Text.Combine(Table.Column(filterToFieldsToGet,"id"),",")
        in
            createFieldsString,

#"(createRenameListFromIds)" = (idsToGetNames as text) =>
    let
        // jiraDomain = "https://rimestechnologies.atlassian.net",
        // idsToGetNames = "summary,customfield_12976,assignee,created",

        idsToGetNamesAsList = Text.Split(Text.Lower(idsToGetNames),","),

        jiraFieldNameList = Json.Document(Web.Contents(jiraDomain & "/rest/api/3/field")),
        fieldRecordsToTable = Table.FromList(jiraFieldNameList, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
        expandFieldRecords = Table.ExpandRecordColumn(fieldRecordsToTable, "Column1", {"id", "key", "name"}, {"id", "key", "name"}),
        addFieldCheck = Table.AddColumn(expandFieldRecords, "getField?", each List.Contains(idsToGetNamesAsList,Text.Lower([id]))),
        filterToFields = Table.SelectRows(addFieldCheck, each ([#"getField?"] = true)),
        addRenameLists = Table.AddColumn(filterToFields, "renameLists", each {[id],[name]}),
        createListOfLists = Table.Column(addRenameLists,"renameLists")
    in
        createListOfLists,

    createQueryTable = 
        Table.FromList(
            List.Generate(
                () => 0, 
                each _ < Json.Document(Web.Contents(jiraDomain & "/rest/api/3/search",
                    [RelativePath=
                        "?fields=key"
                        & "&jql=" & jqlConverted
                    ]))[total], 
                each _ + itemsPerQueryConverted
            )
            , Splitter.SplitByNothing(), null, null, ExtraValues.Error
        ),
    addQueries = Table.AddColumn(createQueryTable, "queryLists", each 
        Json.Document(Web.Contents(
            jiraDomain & "/rest/api/3/search"
            ,[RelativePath=
                "?startAt=" & Text.From([Column1])
                & "&jql=" & jqlConverted
                & "&maxResults=" & Text.From(itemsPerQueryConverted)
                & "&fields=" & Text.From(if fieldsConverted = null then "*all" else #"(convertFieldsNamesToIds)"(fieldsConverted))
            ]
        ))[issues]),
    removeStartAt = Table.RemoveColumns(addQueries,{"Column1"}),
    expandQueryLists = Table.ExpandListColumn(removeStartAt, "queryLists"),
    expandIssues = Table.ExpandRecordColumn(expandQueryLists, "queryLists", {"id", "key", "fields"}, {"id", "key", "fields"}),
    expandFields = 
        if List.First(Table.Column(expandIssues,"fields")) = null
        then expandIssues
        else Table.ExpandRecordColumn(expandIssues, "fields", Record.FieldNames(List.First(Table.Column(expandIssues,"fields"))), Record.FieldNames(List.First(Table.Column(expandIssues,"fields")))),
    renameFields = 
        if List.First(Table.Column(expandIssues,"fields")) = null
        then Table.RemoveColumns(expandFields,{"fields"})
        else Table.RenameColumns(expandFields,#"(createRenameListFromIds)"(Text.Combine(Record.FieldNames(List.First(Table.Column(expandIssues,"fields"))),",")))
in
    renameFields
in Source

 

 

 

 

 

 

Kalp
Regular Visitor

Hi there,
Thanks for sharing this
Is there a modification to this code to add custom fields as well?

DanMcG
Regular Visitor

Hey @Kalp,

 

I think it should work with custom fields.

 

If you put in a JQL query that has custom fields included in its definition, that should work.

v-jingzhang
Community Support
Community Support

Thank you for your sharing in the community! 

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.