From 14bc1ee9bf7c8a9d145d4ecea8809684256a7237 Mon Sep 17 00:00:00 2001 From: Mini256 Date: Thu, 7 Sep 2023 09:23:10 +0800 Subject: [PATCH] queries: add org issues queries --- .../orgs/issues/actions/trends/params.json | 25 +++++ .../orgs/issues/actions/trends/template.sql | 30 +++++ .../orgs/issues/closed-ratio/params.json | 25 +++++ .../orgs/issues/closed-ratio/template.sql | 105 ++++++++++++++++++ .../issue-comments/top-repos/params.json | 31 ++++++ .../issue-comments/top-repos/template.sql | 57 ++++++++++ .../open-to-close-duration/medium/params.json | 25 +++++ .../medium/template.sql | 77 +++++++++++++ .../top-repos/params.json | 31 ++++++ .../top-repos/template.sql | 69 ++++++++++++ .../medium/params.json | 25 +++++ .../medium/template.sql | 89 +++++++++++++++ .../top-repos/params.json | 31 ++++++ .../top-repos/template.sql | 94 ++++++++++++++++ configs/queries/orgs/issues/total/params.json | 25 +++++ .../queries/orgs/issues/total/template.sql | 42 +++++++ .../queries/orgs/issues/trends/params.json | 25 +++++ .../queries/orgs/issues/trends/template.sql | 101 +++++++++++++++++ 18 files changed, 907 insertions(+) create mode 100644 configs/queries/orgs/issues/actions/trends/params.json create mode 100644 configs/queries/orgs/issues/actions/trends/template.sql create mode 100644 configs/queries/orgs/issues/closed-ratio/params.json create mode 100644 configs/queries/orgs/issues/closed-ratio/template.sql create mode 100644 configs/queries/orgs/issues/issue-comments/top-repos/params.json create mode 100644 configs/queries/orgs/issues/issue-comments/top-repos/template.sql create mode 100644 configs/queries/orgs/issues/open-to-close-duration/medium/params.json create mode 100644 configs/queries/orgs/issues/open-to-close-duration/medium/template.sql create mode 100644 configs/queries/orgs/issues/open-to-close-duration/top-repos/params.json create mode 100644 configs/queries/orgs/issues/open-to-close-duration/top-repos/template.sql create mode 100644 configs/queries/orgs/issues/open-to-first-response-duration/medium/params.json create mode 100644 configs/queries/orgs/issues/open-to-first-response-duration/medium/template.sql create mode 100644 configs/queries/orgs/issues/open-to-first-response-duration/top-repos/params.json create mode 100644 configs/queries/orgs/issues/open-to-first-response-duration/top-repos/template.sql create mode 100644 configs/queries/orgs/issues/total/params.json create mode 100644 configs/queries/orgs/issues/total/template.sql create mode 100644 configs/queries/orgs/issues/trends/params.json create mode 100644 configs/queries/orgs/issues/trends/template.sql diff --git a/configs/queries/orgs/issues/actions/trends/params.json b/configs/queries/orgs/issues/actions/trends/params.json new file mode 100644 index 00000000000..93034f6380d --- /dev/null +++ b/configs/queries/orgs/issues/actions/trends/params.json @@ -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" + } + ] +} diff --git a/configs/queries/orgs/issues/actions/trends/template.sql b/configs/queries/orgs/issues/actions/trends/template.sql new file mode 100644 index 00000000000..679a2f8095a --- /dev/null +++ b/configs/queries/orgs/issues/actions/trends/template.sql @@ -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 \ No newline at end of file diff --git a/configs/queries/orgs/issues/closed-ratio/params.json b/configs/queries/orgs/issues/closed-ratio/params.json new file mode 100644 index 00000000000..93034f6380d --- /dev/null +++ b/configs/queries/orgs/issues/closed-ratio/params.json @@ -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" + } + ] +} diff --git a/configs/queries/orgs/issues/closed-ratio/template.sql b/configs/queries/orgs/issues/closed-ratio/template.sql new file mode 100644 index 00000000000..faa8fbba1c7 --- /dev/null +++ b/configs/queries/orgs/issues/closed-ratio/template.sql @@ -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 +; \ No newline at end of file diff --git a/configs/queries/orgs/issues/issue-comments/top-repos/params.json b/configs/queries/orgs/issues/issue-comments/top-repos/params.json new file mode 100644 index 00000000000..dc9cf8c1965 --- /dev/null +++ b/configs/queries/orgs/issues/issue-comments/top-repos/params.json @@ -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 + } + ] +} diff --git a/configs/queries/orgs/issues/issue-comments/top-repos/template.sql b/configs/queries/orgs/issues/issue-comments/top-repos/template.sql new file mode 100644 index 00000000000..eadc5d37536 --- /dev/null +++ b/configs/queries/orgs/issues/issue-comments/top-repos/template.sql @@ -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 }} \ No newline at end of file diff --git a/configs/queries/orgs/issues/open-to-close-duration/medium/params.json b/configs/queries/orgs/issues/open-to-close-duration/medium/params.json new file mode 100644 index 00000000000..93034f6380d --- /dev/null +++ b/configs/queries/orgs/issues/open-to-close-duration/medium/params.json @@ -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" + } + ] +} diff --git a/configs/queries/orgs/issues/open-to-close-duration/medium/template.sql b/configs/queries/orgs/issues/open-to-close-duration/medium/template.sql new file mode 100644 index 00000000000..b071731c858 --- /dev/null +++ b/configs/queries/orgs/issues/open-to-close-duration/medium/template.sql @@ -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 +; \ No newline at end of file diff --git a/configs/queries/orgs/issues/open-to-close-duration/top-repos/params.json b/configs/queries/orgs/issues/open-to-close-duration/top-repos/params.json new file mode 100644 index 00000000000..a94aa088836 --- /dev/null +++ b/configs/queries/orgs/issues/open-to-close-duration/top-repos/params.json @@ -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": [10, 20, 30, 40, 50], + "default": 10 + } + ] +} diff --git a/configs/queries/orgs/issues/open-to-close-duration/top-repos/template.sql b/configs/queries/orgs/issues/open-to-close-duration/top-repos/template.sql new file mode 100644 index 00000000000..2567af73c60 --- /dev/null +++ b/configs/queries/orgs/issues/open-to-close-duration/top-repos/template.sql @@ -0,0 +1,69 @@ +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 %} +), issues_with_opened_at AS ( + SELECT + repo_id, number, created_at AS opened_at + 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 %} +), 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 + pwo.repo_id, + TIMESTAMPDIFF(SECOND, pwo.opened_at, pwc.closed_at) / 3600 AS hours, + PERCENT_RANK() OVER (PARTITION BY pwo.repo_id ORDER BY (pwc.closed_at - pwo.opened_at)) AS percentile + FROM issues_with_opened_at pwo + JOIN issues_with_closed_at pwc USING (repo_id, number) + WHERE pwc.closed_at > pwo.opened_at +), tdiff_percentiles AS ( + SELECT + repo_id, + MAX(CASE WHEN percentile <= 0 THEN hours END) AS p0, + MAX(CASE WHEN percentile <= 0.25 THEN hours END) AS p25, + MAX(CASE WHEN percentile <= 0.5 THEN hours END) AS p50, + MAX(CASE WHEN percentile <= 0.75 THEN hours END) AS p75, + MAX(CASE WHEN percentile <= 1 THEN hours END) AS p100 + FROM tdiff + GROUP BY repo_id +) +SELECT + r.repo_id, + r.repo_name, + p0, + p25, + p50, + p75, + p100 +FROM repos r +JOIN tdiff_percentiles tp USING (repo_id) +ORDER BY p50 +LIMIT {{n}} +; diff --git a/configs/queries/orgs/issues/open-to-first-response-duration/medium/params.json b/configs/queries/orgs/issues/open-to-first-response-duration/medium/params.json new file mode 100644 index 00000000000..93034f6380d --- /dev/null +++ b/configs/queries/orgs/issues/open-to-first-response-duration/medium/params.json @@ -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" + } + ] +} diff --git a/configs/queries/orgs/issues/open-to-first-response-duration/medium/template.sql b/configs/queries/orgs/issues/open-to-first-response-duration/medium/template.sql new file mode 100644 index 00000000000..7d9d00d7f39 --- /dev/null +++ b/configs/queries/orgs/issues/open-to-first-response-duration/medium/template.sql @@ -0,0 +1,89 @@ +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, + actor_login AS opened_by, + 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_first_responsed_at AS ( + SELECT + repo_id, + number, + actor_login AS first_responsed_by, + created_at AS first_responsed_at + FROM github_events ge + WHERE + ge.repo_id IN (SELECT repo_id FROM repos) + -- Events that are considered as first response. + AND ( + (ge.type = 'IssuesEvent' AND ge.action = 'closed') OR + (ge.type = 'IssueCommentEvent' AND ge.action = 'created') + ) + -- Exclude bot users. + AND ge.actor_login NOT LIKE '%bot%' + {% 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, iwr.first_responsed_at) / 3600 AS hours, + PERCENT_RANK() OVER (PARTITION BY iwo.period ORDER BY (iwr.first_responsed_at - iwo.opened_at)) AS percentile + FROM issues_with_opened_at iwo + JOIN issues_with_first_responsed_at iwr USING (repo_id, number) + WHERE + iwr.first_responsed_at > iwo.opened_at + -- Exclude self-response. + AND iwr.first_responsed_by != iwo.opened_by +), 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 +; \ No newline at end of file diff --git a/configs/queries/orgs/issues/open-to-first-response-duration/top-repos/params.json b/configs/queries/orgs/issues/open-to-first-response-duration/top-repos/params.json new file mode 100644 index 00000000000..a94aa088836 --- /dev/null +++ b/configs/queries/orgs/issues/open-to-first-response-duration/top-repos/params.json @@ -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": [10, 20, 30, 40, 50], + "default": 10 + } + ] +} diff --git a/configs/queries/orgs/issues/open-to-first-response-duration/top-repos/template.sql b/configs/queries/orgs/issues/open-to-first-response-duration/top-repos/template.sql new file mode 100644 index 00000000000..5b24e2a0f40 --- /dev/null +++ b/configs/queries/orgs/issues/open-to-first-response-duration/top-repos/template.sql @@ -0,0 +1,94 @@ +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 %} +), issues_with_opened_at AS ( + SELECT + repo_id, + number, + actor_login AS opened_by, + created_at AS opened_at + 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 %} +), issues_with_first_response_at AS ( + SELECT + repo_id, + number, + responsed_by AS first_responsed_by, + responsed_at AS first_responsed_at + FROM ( + SELECT + repo_id, + number, + actor_login AS responsed_by, + created_at AS responsed_at, + ROW_NUMBER() OVER (PARTITION BY repo_id, number ORDER BY created_at) AS times + FROM github_events ge + WHERE + ge.repo_id IN (SELECT repo_id FROM repos) + -- Events that are considered as first response. + AND ( + (ge.type = 'IssuesEvent' AND ge.action = 'closed') OR + (ge.type = 'IssueCommentEvent' AND ge.action = 'created') + ) + -- Exclude bot users. + AND ge.actor_login NOT LIKE '%bot%' + {% 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 %} + ) sub + WHERE + -- Keep only the first response. + times = 1 +), tdiff AS ( + SELECT + iwo.repo_id, + TIMESTAMPDIFF(SECOND, iwo.opened_at, iwr.first_responsed_at) / 3600 AS hours, + PERCENT_RANK() OVER (PARTITION BY iwo.repo_id ORDER BY (iwr.first_responsed_at - iwo.opened_at)) AS percentile + FROM issues_with_opened_at iwo + JOIN issues_with_first_response_at iwr USING (repo_id, number) + WHERE + iwr.first_responsed_at > iwo.opened_at + -- Exclude self-response. + AND iwr.first_responsed_by != iwo.opened_by +), tdiff_percentiles AS ( + SELECT + repo_id, + MAX(CASE WHEN percentile <= 0 THEN hours END) AS p0, + MAX(CASE WHEN percentile <= 0.25 THEN hours END) AS p25, + MAX(CASE WHEN percentile <= 0.5 THEN hours END) AS p50, + MAX(CASE WHEN percentile <= 0.75 THEN hours END) AS p75, + MAX(CASE WHEN percentile <= 1 THEN hours END) AS p100 + FROM tdiff + GROUP BY repo_id +) +SELECT + r.repo_id, + r.repo_name, + p0, + p25, + p50, + p75, + p100 +FROM repos r +JOIN tdiff_percentiles tp USING (repo_id) +ORDER BY p50 +LIMIT {{n}} +; diff --git a/configs/queries/orgs/issues/total/params.json b/configs/queries/orgs/issues/total/params.json new file mode 100644 index 00000000000..93034f6380d --- /dev/null +++ b/configs/queries/orgs/issues/total/params.json @@ -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" + } + ] +} diff --git a/configs/queries/orgs/issues/total/template.sql b/configs/queries/orgs/issues/total/template.sql new file mode 100644 index 00000000000..c1e92e66019 --- /dev/null +++ b/configs/queries/orgs/issues/total/template.sql @@ -0,0 +1,42 @@ +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_by_period AS ( + SELECT + {% 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, + COUNT(*) AS issues + 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 %} + GROUP BY period +), current_period_issues AS ( + SELECT issues FROM opened_issues_by_period WHERE period = 0 +), past_period_issues AS ( + SELECT issues FROM opened_issues_by_period WHERE period = 1 +) +SELECT + IFNULL(cpp.issues, 0) AS current_period_total, + IFNULL(ppp.issues, 0) AS past_period_total, + ROUND((cpp.issues - ppp.issues) / ppp.issues * 100, 2) AS growth_percentage +FROM current_period_issues cpp +LEFT JOIN past_period_issues ppp ON 1 = 1 +; + diff --git a/configs/queries/orgs/issues/trends/params.json b/configs/queries/orgs/issues/trends/params.json new file mode 100644 index 00000000000..93034f6380d --- /dev/null +++ b/configs/queries/orgs/issues/trends/params.json @@ -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" + } + ] +} diff --git a/configs/queries/orgs/issues/trends/template.sql b/configs/queries/orgs/issues/trends/template.sql new file mode 100644 index 00000000000..3f7af8bf37c --- /dev/null +++ b/configs/queries/orgs/issues/trends/template.sql @@ -0,0 +1,101 @@ +WITH RECURSIVE seq(idx, current_period_day, past_period_day) AS ( + SELECT + 1 AS idx, + {% case period %} + {% when 'past_7_days', 'past_28_days', 'past_90_days' %} DATE_FORMAT(CURRENT_DATE(), '%Y-%m-%d') + {% when 'past_12_months' %} DATE_FORMAT(CURRENT_DATE(), '%Y-%m-01') + {% endcase %} AS current_period_day, + {% case period %} + {% when 'past_7_days' %} DATE_FORMAT(DATE_SUB(CURRENT_DATE(), INTERVAL 7 DAY), '%Y-%m-%d') + {% when 'past_28_days' %} DATE_FORMAT(DATE_SUB(CURRENT_DATE(), INTERVAL 28 DAY), '%Y-%m-%d') + {% when 'past_90_days' %} DATE_FORMAT(DATE_SUB(CURRENT_DATE(), INTERVAL 90 DAY), '%Y-%m-%d') + {% when 'past_12_months' %} DATE_FORMAT(DATE_SUB(CURRENT_DATE(), INTERVAL 12 MONTH), '%Y-%m-01') + {% endcase %} AS past_period_day + UNION ALL + SELECT + idx + 1 AS idx, + {% case period %} + {% when 'past_7_days', 'past_28_days', 'past_90_days' %} DATE_FORMAT(DATE_SUB(CURRENT_DATE(), INTERVAL idx DAY), '%Y-%m-%d') + {% when 'past_12_months' %} DATE_FORMAT(DATE_SUB(CURRENT_DATE(), INTERVAL idx MONTH), '%Y-%m-01') + {% endcase %} AS current_period_day, + {% case period %} + {% when 'past_7_days' %} DATE_FORMAT(DATE_SUB(CURRENT_DATE(), INTERVAL idx + 7 DAY), '%Y-%m-%d') + {% when 'past_28_days' %} DATE_FORMAT(DATE_SUB(CURRENT_DATE(), INTERVAL idx + 28 DAY), '%Y-%m-%d') + {% when 'past_90_days' %} DATE_FORMAT(DATE_SUB(CURRENT_DATE(), INTERVAL idx + 90 DAY), '%Y-%m-%d') + {% when 'past_12_months' %} DATE_FORMAT(DATE_SUB(CURRENT_DATE(), INTERVAL idx + 12 MONTH), '%Y-%m-01') + {% endcase %} AS past_period_day + FROM seq + WHERE + 1 = 1 + {% case period %} + {% when 'past_7_days' %} AND idx < 7 + {% when 'past_28_days' %} AND idx < 28 + {% when 'past_90_days' %} AND idx < 90 + {% when 'past_12_months' %} AND idx < 12 + {% endcase %} +), 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 %} +), group_by_day AS ( + SELECT + {% case period %} + {% when 'past_7_days' %} TIMESTAMPDIFF(DAY, day, CURRENT_DATE()) % 7 + 1 + {% when 'past_28_days' %} TIMESTAMPDIFF(DAY, day, CURRENT_DATE()) % 28 + 1 + {% when 'past_90_days' %} TIMESTAMPDIFF(DAY, day, CURRENT_DATE()) % 90 + 1 + {% when 'past_12_months' %} TIMESTAMPDIFF(MONTH, day, CURRENT_DATE()) % 12 + 1 + {% endcase %} AS idx, + -- Divide periods. + {% case period %} + {% when 'past_7_days' %} TIMESTAMPDIFF(DAY, day, CURRENT_DATE()) DIV 7 + {% when 'past_28_days' %} TIMESTAMPDIFF(DAY, day, CURRENT_DATE()) DIV 28 + {% when 'past_90_days' %} TIMESTAMPDIFF(DAY, day, CURRENT_DATE()) DIV 90 + {% when 'past_12_months' %} TIMESTAMPDIFF(MONTH, day, CURRENT_DATE()) DIV 12 + {% endcase %} AS period, + day, + issues + FROM ( + SELECT + {% case period %} + {% when 'past_7_days', 'past_28_days', 'past_90_days' %} DATE_FORMAT(created_at, '%Y-%m-%d') + {% when 'past_12_months' %} DATE_FORMAT(created_at, '%Y-%m-01') + {% endcase %} AS day, + COUNT(*) AS issues + FROM github_events ge + WHERE + repo_id IN (SELECT repo_id FROM repos) + AND type = 'IssuesEvent' + AND action = 'opened' + {% case period %} + {% when 'past_7_days' %} AND created_at > (CURRENT_DATE() - INTERVAL 14 DAY) + {% when 'past_28_days' %} AND created_at > (CURRENT_DATE() - INTERVAL 56 DAY) + {% when 'past_90_days' %} AND created_at > (CURRENT_DATE() - INTERVAL 180 DAY) + {% when 'past_12_months' %} AND created_at > (CURRENT_DATE() - INTERVAL 24 MONTH) + {% endcase %} + GROUP BY day + ORDER BY day + ) sub +), current_period AS ( + SELECT idx, day, issues + FROM group_by_day + WHERE period = 0 +), past_period AS ( + SELECT idx, day, issues + FROM group_by_day + WHERE period = 1 +) +SELECT + s.idx AS idx, + s.current_period_day AS current_period_day, + IFNULL(cp.issues, 0) AS current_period_day_total, + s.past_period_day AS past_period_day, + IFNULL(pp.issues, 0) AS past_period_day_total +FROM seq s +LEFT JOIN current_period cp ON s.idx = cp.idx +LEFT JOIN past_period pp ON s.idx = pp.idx +ORDER BY idx +; \ No newline at end of file