Skip to content

Commit

Permalink
queries: add org issues queries (#1606)
Browse files Browse the repository at this point in the history
  • Loading branch information
Mini256 authored Sep 7, 2023
1 parent 62f9f51 commit 801f842
Show file tree
Hide file tree
Showing 18 changed files with 907 additions and 0 deletions.
25 changes: 25 additions & 0 deletions configs/queries/orgs/issues/actions/trends/params.json
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
{
"cacheHours": 1,
"engine": "liquid",
"params": [
{
"name": "ownerId",
"replaces": "11855343",
"type": "integer"
},
{
"name": "repoIds",
"replaces": "41986369",
"type": "array",
"default": [],
"itemType": "integer",
"maxArrayLength": 50
},
{
"name": "period",
"type": "string",
"enums": ["past_7_days", "past_28_days", "past_90_days", "past_12_months"],
"default": "past_28_days"
}
]
}
30 changes: 30 additions & 0 deletions configs/queries/orgs/issues/actions/trends/template.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,30 @@
WITH repos AS (
SELECT
gr.repo_id
FROM github_repos gr
WHERE
gr.owner_id = {{ownerId}}
{% if repoIds.size > 0 %}
AND gr.repo_id IN ({{ repoIds | join: ',' }})
{% endif %}
)
SELECT
ge.action AS action_type,
{% case period %}
{% when 'past_7_days', 'past_28_days', 'past_90_days' %} DATE(created_at)
{% when 'past_12_months' %} DATE_FORMAT(created_at, '%Y-%m-01')
{% endcase %} AS date,
COUNT(*) AS issues
FROM github_events ge
WHERE
ge.repo_id IN (SELECT repo_id FROM repos)
AND ge.type = 'IssuesEvent'
AND ge.action IN ('opened', 'closed')
{% case period %}
{% when 'past_7_days' %} AND created_at > (NOW() - INTERVAL 7 DAY)
{% when 'past_28_days' %} AND created_at > (NOW() - INTERVAL 28 DAY)
{% when 'past_90_days' %} AND created_at > (NOW() - INTERVAL 90 DAY)
{% when 'past_12_months' %} AND created_at > (NOW() - INTERVAL 12 MONTH)
{% endcase %}
GROUP BY action, date
ORDER BY date, action_type
25 changes: 25 additions & 0 deletions configs/queries/orgs/issues/closed-ratio/params.json
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
{
"cacheHours": 1,
"engine": "liquid",
"params": [
{
"name": "ownerId",
"replaces": "11855343",
"type": "integer"
},
{
"name": "repoIds",
"replaces": "41986369",
"type": "array",
"default": [],
"itemType": "integer",
"maxArrayLength": 50
},
{
"name": "period",
"type": "string",
"enums": ["past_7_days", "past_28_days", "past_90_days", "past_12_months"],
"default": "past_28_days"
}
]
}
105 changes: 105 additions & 0 deletions configs/queries/orgs/issues/closed-ratio/template.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,105 @@
WITH repos AS (
SELECT gr.repo_id
FROM github_repos gr
WHERE
gr.owner_id = {{ownerId}}
{% if repoIds.size > 0 %}
AND gr.repo_id IN ({{ repoIds | join: ',' }})
{% endif %}
), opened_issues AS (
SELECT
sub.repo_id, sub.number, sub.opened_actor_login, sub.opened_at,
{% case period %}
{% when 'past_7_days' %} TIMESTAMPDIFF(DAY, opened_at, NOW()) DIV 7
{% when 'past_28_days' %} TIMESTAMPDIFF(DAY, opened_at, NOW()) DIV 28
{% when 'past_90_days' %} TIMESTAMPDIFF(DAY, opened_at, NOW()) DIV 90
{% when 'past_12_months' %} TIMESTAMPDIFF(MONTH, opened_at, NOW()) DIV 12
{% endcase %} AS period
FROM (
SELECT
ge.repo_id,
ge.number,
ge.actor_login AS opened_actor_login,
ge.created_at AS opened_at,
ROW_NUMBER() OVER (PARTITION BY ge.repo_id, ge.number ORDER BY ge.created_at) AS times
FROM github_events ge
WHERE
ge.repo_id IN (SELECT repo_id FROM repos)
AND ge.type = 'IssuesEvent'
AND ge.action = 'opened'
{% case period %}
{% when 'past_7_days' %} AND created_at > (NOW() - INTERVAL 14 DAY)
{% when 'past_28_days' %} AND created_at > (NOW() - INTERVAL 56 DAY)
{% when 'past_90_days' %} AND created_at > (NOW() - INTERVAL 180 DAY)
{% when 'past_12_months' %} AND created_at > (NOW() - INTERVAL 24 MONTH)
{% endcase %}
) sub
WHERE
# Only consider the first opened event.
sub.times = 1
), closed_issues AS (
SELECT
sub.repo_id,
sub.number,
sub.closer_login,
sub.closed_at,
{% case period %}
{% when 'past_7_days' %} TIMESTAMPDIFF(DAY, closed_at, NOW()) DIV 7
{% when 'past_28_days' %} TIMESTAMPDIFF(DAY, closed_at, NOW()) DIV 28
{% when 'past_90_days' %} TIMESTAMPDIFF(DAY, closed_at, NOW()) DIV 90
{% when 'past_12_months' %} TIMESTAMPDIFF(MONTH, closed_at, NOW()) DIV 12
{% endcase %} AS period
FROM (
SELECT
ge.repo_id,
ge.number,
ge.actor_login AS closer_login,
ge.created_at AS closed_at,
ROW_NUMBER() OVER (PARTITION BY ge.repo_id, ge.number ORDER BY ge.created_at) AS times
FROM github_events ge
WHERE
ge.repo_id IN (SELECT repo_id FROM repos)
AND ge.type = 'IssuesEvent'
AND ge.action = 'closed'
{% case period %}
{% when 'past_7_days' %} AND ge.created_at > (NOW() - INTERVAL 14 DAY)
{% when 'past_28_days' %} AND ge.created_at > (NOW() - INTERVAL 56 DAY)
{% when 'past_90_days' %} AND ge.created_at > (NOW() - INTERVAL 180 DAY)
{% when 'past_12_months' %} AND ge.created_at > (NOW() - INTERVAL 24 MONTH)
{% endcase %}
) sub
# Only consider merged issues that were opened in the last 28 days.
JOIN opened_issues op USING (repo_id, number)
WHERE
# Only consider the first merged event.
sub.times = 1
), opened_issues_per_period AS (
SELECT op.period, COUNT(*) AS opened_issues
FROM opened_issues op
GROUP BY op.period
), closed_issues_per_period AS (
SELECT rp.period, COUNT(*) AS closed_issues
FROM closed_issues rp
GROUP BY rp.period
), current_period_opened_issues AS (
SELECT * FROM opened_issues_per_period WHERE period = 0
), past_period_opened_issues AS (
SELECT * FROM opened_issues_per_period WHERE period = 1
), current_period_closed_issues AS (
SELECT * FROM closed_issues_per_period WHERE period = 0
), past_period_closed_issues AS (
SELECT * FROM closed_issues_per_period WHERE period = 1
)
SELECT
cpoi.opened_issues AS current_period_opened_issues,
cpci.closed_issues AS current_period_closed_issues,
ROUND(cpci.closed_issues / cpoi.opened_issues, 2) AS current_period_closed_ratio,
ppoi.opened_issues AS past_period_opened_issues,
ppci.closed_issues AS past_period_closed_issues,
ROUND(ppci.closed_issues / ppoi.opened_issues, 2) AS past_period_closed_ratio,
ROUND((cpci.closed_issues / cpoi.opened_issues) - (ppci.closed_issues / ppoi.opened_issues), 2) AS closed_ratio_change
FROM current_period_opened_issues cpoi
LEFT JOIN current_period_closed_issues cpci ON 1 = 1
LEFT JOIN past_period_opened_issues ppoi ON 1 = 1
LEFT JOIN past_period_closed_issues ppci ON 1 = 1
;
31 changes: 31 additions & 0 deletions configs/queries/orgs/issues/issue-comments/top-repos/params.json
Original file line number Diff line number Diff line change
@@ -0,0 +1,31 @@
{
"cacheHours": 1,
"engine": "liquid",
"params": [
{
"name": "ownerId",
"replaces": "11855343",
"type": "integer"
},
{
"name": "repoIds",
"replaces": "41986369",
"type": "array",
"default": [],
"itemType": "integer",
"maxArrayLength": 50
},
{
"name": "period",
"type": "string",
"enums": ["past_7_days", "past_28_days", "past_90_days", "past_12_months"],
"default": "past_28_days"
},
{
"name": "n",
"type": "integer",
"enums": [5, 10, 20, 40, 50],
"default": 10
}
]
}
57 changes: 57 additions & 0 deletions configs/queries/orgs/issues/issue-comments/top-repos/template.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,57 @@
WITH repos AS (
SELECT
gr.repo_id, gr.repo_name
FROM github_repos gr
WHERE
gr.owner_id = {{ownerId}}
{% if repoIds.size > 0 %}
AND gr.repo_id IN ({{ repoIds | join: ',' }})
{% endif %}
), opened_issues AS (
SELECT
ge.repo_id, number
FROM github_events ge
WHERE
ge.repo_id IN (SELECT repo_id FROM repos)
AND ge.type = 'IssuesEvent'
AND ge.action = 'opened'
{% case period %}
{% when 'past_7_days' %} AND created_at > (NOW() - INTERVAL 7 DAY)
{% when 'past_28_days' %} AND created_at > (NOW() - INTERVAL 28 DAY)
{% when 'past_90_days' %} AND created_at > (NOW() - INTERVAL 90 DAY)
{% when 'past_12_months' %} AND created_at > (NOW() - INTERVAL 12 MONTH)
{% endcase %}
GROUP BY ge.repo_id
), issues_by_repo AS (
SELECT repo_id, COUNT(*) AS issues
FROM opened_issues oi
GROUP BY repo_id
), comments_by_repo AS (
SELECT
ge.repo_id, COUNT(*) AS comments
FROM github_events ge
-- Note: Only consider comments on issues that were opened during the period.
JOIN opened_issues oi ON oi.repo_id = ge.repo_id AND oi.number = ge.number
WHERE
ge.repo_id IN (SELECT repo_id FROM repos)
AND ge.type = 'IssueCommentEvent'
AND ge.action = 'created'
{% case period %}
{% when 'past_7_days' %} AND created_at > (NOW() - INTERVAL 7 DAY)
{% when 'past_28_days' %} AND created_at > (NOW() - INTERVAL 28 DAY)
{% when 'past_90_days' %} AND created_at > (NOW() - INTERVAL 90 DAY)
{% when 'past_12_months' %} AND created_at > (NOW() - INTERVAL 12 MONTH)
{% endcase %}
GROUP BY ge.repo_id
)
SELECT
r.repo_id,
r.repo_name,
ibr.issues AS issues,
cbr.comments AS comments,
ROUND(cbr.comments / ibr.issues, 2) AS comments_per_issue
FROM repos r
JOIN issues_by_repo ibr ON ibr.repo_id = r.repo_id
JOIN comments_by_repo cbr ON cbr.repo_id = r.repo_id
ORDER BY comments_per_issue DESC
LIMIT {{ n }}
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
{
"cacheHours": 1,
"engine": "liquid",
"params": [
{
"name": "ownerId",
"replaces": "11855343",
"type": "integer"
},
{
"name": "repoIds",
"replaces": "41986369",
"type": "array",
"default": [],
"itemType": "integer",
"maxArrayLength": 50
},
{
"name": "period",
"type": "string",
"enums": ["past_7_days", "past_28_days", "past_90_days", "past_12_months"],
"default": "past_28_days"
}
]
}
Original file line number Diff line number Diff line change
@@ -0,0 +1,77 @@
WITH repos AS (
SELECT gr.repo_id
FROM github_repos gr
WHERE
gr.owner_id = {{ownerId}}
{% if repoIds.size > 0 %}
AND gr.repo_id IN ({{ repoIds | join: ',' }})
{% endif %}
), issues_with_opened_at AS (
SELECT
repo_id,
number,
created_at AS opened_at,
{% case period %}
{% when 'past_7_days' %} TIMESTAMPDIFF(DAY, created_at, NOW()) DIV 7
{% when 'past_28_days' %} TIMESTAMPDIFF(DAY, created_at, NOW()) DIV 28
{% when 'past_90_days' %} TIMESTAMPDIFF(DAY, created_at, NOW()) DIV 90
{% when 'past_12_months' %} TIMESTAMPDIFF(MONTH, created_at, NOW()) DIV 12
{% endcase %} AS period
FROM github_events ge
WHERE
ge.repo_id IN (SELECT repo_id FROM repos)
AND ge.type = 'IssuesEvent'
AND ge.action = 'opened'
{% case period %}
{% when 'past_7_days' %} AND created_at > (NOW() - INTERVAL 14 DAY)
{% when 'past_28_days' %} AND created_at > (NOW() - INTERVAL 56 DAY)
{% when 'past_90_days' %} AND created_at > (NOW() - INTERVAL 180 DAY)
{% when 'past_12_months' %} AND created_at > (NOW() - INTERVAL 24 MONTH)
{% endcase %}
), issues_with_closed_at AS (
SELECT
repo_id,
number,
created_at AS closed_at
FROM github_events ge
WHERE
ge.repo_id IN (SELECT repo_id FROM repos)
AND ge.type = 'IssuesEvent'
AND ge.action = 'closed'
{% case period %}
{% when 'past_7_days' %} AND created_at > (NOW() - INTERVAL 14 DAY)
{% when 'past_28_days' %} AND created_at > (NOW() - INTERVAL 56 DAY)
{% when 'past_90_days' %} AND created_at > (NOW() - INTERVAL 180 DAY)
{% when 'past_12_months' %} AND created_at > (NOW() - INTERVAL 24 MONTH)
{% endcase %}
), tdiff AS (
SELECT
iwo.repo_id,
iwo.period,
TIMESTAMPDIFF(SECOND, iwo.opened_at, iwc.closed_at) / 3600 AS hours,
PERCENT_RANK() OVER (PARTITION BY iwo.period ORDER BY (iwc.closed_at - iwo.opened_at)) AS percentile
FROM issues_with_opened_at iwo
JOIN issues_with_closed_at iwc USING (repo_id, number)
WHERE iwc.closed_at > iwo.opened_at
), current_period_medium AS (
SELECT
MAX(hours) AS p50
FROM tdiff
WHERE
percentile <= 0.5
AND period = 0
), past_period_medium AS (
SELECT
MAX(hours) AS p50
FROM tdiff
WHERE
percentile <= 0.5
AND period = 1
)
SELECT
ROUND(cpm.p50, 2) AS current_period_medium,
ROUND(ppm.p50, 2) AS past_period_medium,
ROUND((cpm.p50 - ppm.p50) / ppm.p50, 2) AS percentage
FROM
current_period_medium cpm, past_period_medium ppm
;
Loading

0 comments on commit 801f842

Please sign in to comment.