Create
cancel
Showing results for 
Search instead for 
Did you mean: 
Sign up Log in
Celebration

Earn badges and make progress

You're on your way to the next level! Join the Kudos program to earn points and save your progress.

Deleted user Avatar
Deleted user

Level 1: Seed

25 / 150 points

Next: Root

Avatar

1 badge earned

Collect

Participate in fun challenges

Challenges come and go, but your rewards stay with you. Do more to earn more!

Challenges
Coins

Gift kudos to your peers

What goes around comes around! Share the love by gifting kudos to your peers.

Recognition
Ribbon

Rise up in the ranks

Keep earning points to reach the top of the leaderboard. It resets every quarter so you always have a chance!

Leaderboard

SQL Query to mimic the results in SprintReport - Solved

Just wanted to share some query on what i've been struggling for a while now, basically i needed to have a query (sql) where i could see information similar to what is shown in the Sprint report, and show some graphics on what was committed at the beginning of each sprint and what was part of a scope change after the sprint was started.

it toke me a while to come up with a solution and finally i found out a way, hope some one else find this use-full in your implementation.

SELECT ji.id AS issueid,
concat(p.pkey, '-', ji.issuenum)::character varying AS IssueKey,
s."ID" AS sprintid,
s."NAME" as SprintName,
to_timestamp((s."START_DATE" / 1000)::double precision) AS SprintStart,
to_timestamp((s."END_DATE" / 1000)::double precision) AS SprintEnd,
to_timestamp((s."COMPLETE_DATE" / 1000)::double precision) AS SprintCompleted,
p.pname as ProjectName,
-- This Here is the tricky part, we have to evaluate two sources of info, ChangeGroup and CustomFieldValue
-- If ChangeGroup returns null (probably bc the issue was created directly into the sprint)
-- Then we have to Search in the customFieldValue.created value (sprint fieldId is 10001 in my implementation)
COALESCE((SELECT cg.created
FROM Changegroup cg -- Searching the changegroup/change itme tables
INNER JOIN ChangeItem ci on ci.groupid = cg.id AND ci.field = 'Sprint'
WHERE cg.issueid = ji.id
AND ci.newvalue ~ s."ID"::text
AND NOT COALESCE(ci.oldvalue,'') ~ s."ID"::text
ORDER BY cg.id
LIMIT 1),
(SELECT TO_TIMESTAMP(cfv.updated/1000) --if null was returned from the previous query then we just search the
-- value in the customfieldvalue.updated
FROM customfieldvalue cfv
WHERE cfv.issue = ji.id AND cfv.customfield=10001::numeric
AND cfv.stringvalue::bigint = s."ID"
LIMIT 1)) AS AddedToSprintDate
FROM jiraissue ji
JOIN project p ON ji.project = p.id
JOIN nodeassociation na ON p.id = na.source_node_id AND na.sink_node_entity::text = 'ProjectCategory'::text
JOIN customfieldvalue cfv ON cfv.issue = ji.id
JOIN "AO_60DB71_SPRINT" s ON cfv.customfield = 10001::numeric AND s."ID" = cfv.stringvalue::bigint
JOIN issuetype it ON ji.issuetype::text = it.id::text
WHERE it.pname::text = 'Story'::text
AND s."ID" = 3169 --Finally filter by the sprintid you want the report from
ORDER BY s."ID";

1 comment

this is awesome !!! it worked for me and I exported the data to chamostudio.

 

well done

Comment

Log in or Sign up to comment