Skip to content

Commit

Permalink
queries: add org repos queries (#1607)
Browse files Browse the repository at this point in the history
  • Loading branch information
Mini256 authored Sep 7, 2023
1 parent 25df469 commit 9653dff
Show file tree
Hide file tree
Showing 8 changed files with 176 additions and 4 deletions.
4 changes: 2 additions & 2 deletions configs/queries/orgs/issues/closed-ratio/template.sql
Original file line number Diff line number Diff line change
Expand Up @@ -68,10 +68,10 @@ WITH repos AS (
{% 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.
# Only consider closed issues that were opened in the last 28 days.
JOIN opened_issues op USING (repo_id, number)
WHERE
# Only consider the first merged event.
# Only consider the first closed event.
sub.times = 1
), opened_issues_per_period AS (
SELECT op.period, COUNT(*) AS opened_issues
Expand Down
11 changes: 11 additions & 0 deletions configs/queries/orgs/overview/params.json
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
{
"cacheHours": 1,
"engine": "liquid",
"params": [
{
"name": "ownerId",
"replaces": "11855343",
"type": "integer"
}
]
}
28 changes: 28 additions & 0 deletions configs/queries/orgs/overview/template.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,28 @@
WITH org AS (
SELECT id
FROM github_users
-- Note: Calculated only when there is no value for stars_total and participant_total.
WHERE id = {{ownerId}} AND (stars_total IS NULL OR participant_total IS NULL)
), repos AS (
SELECT repo_id
FROM github_repos gr
WHERE gr.owner_id = (SELECT id FROM org LIMIT 1)
), stars_total AS (
SELECT SUM(stars) AS stars
FROM github_repos gr
WHERE gr.owner_id = (SELECT id FROM org LIMIT 1)
), participant_total AS (
SELECT COUNT(DISTINCT ge.actor_login) AS participants
FROM github_events ge
WHERE
ge.repo_id IN (SELECT repo_id FROM repos)
AND ge.type IN ('PullRequestEvent', 'PullRequestReviewEvent', 'IssuesEvent', 'IssueCommentEvent', 'PushEvent')
AND ge.action IN ('opened', 'created', '')
)
SELECT
IFNULL(stars_total, stars) AS stars,
IFNULL(participant_total, participants) AS participants
FROM
github_users gu, stars_total, participant_total
WHERE
id = {{ownerId}}
4 changes: 2 additions & 2 deletions configs/queries/orgs/participants/engagements/template.sql
Original file line number Diff line number Diff line change
Expand Up @@ -14,8 +14,8 @@ WITH repos AS (
FROM github_events ge
WHERE
repo_id IN (SELECT repo_id FROM repos)
AND ge.type IN ('PullRequestEvent', 'PullRequestReviewEvent', 'IssuesEvent', 'IssueCommentEvent', 'PushEvent')
AND ge.action IN ('opened', 'created', '')
AND ge.type IN ('PullRequestEvent', 'PullRequestReviewEvent', 'IssuesEvent', 'IssueCommentEvent', 'PushEvent')
AND ge.action IN ('opened', 'created', '')
{% case period %}
{% when 'past_7_days' %} AND created_at > (CURRENT_DATE() - INTERVAL 7 DAY)
{% when 'past_28_days' %} AND created_at > (CURRENT_DATE() - INTERVAL 28 DAY)
Expand Down
25 changes: 25 additions & 0 deletions configs/queries/orgs/repos/active/ranking/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"
}
]
}
40 changes: 40 additions & 0 deletions configs/queries/orgs/repos/active/ranking/template.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,40 @@
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 %}
), repos_with_stars AS (
SELECT
repo_id,
COUNT(*) AS stars
FROM github_events ge
WHERE
ge.repo_id IN (SELECT repo_id FROM repos)
AND ge.type IN ('PullRequestEvent', 'PullRequestReviewEvent', 'IssuesEvent', 'IssueCommentEvent', 'PushEvent')
AND ge.action IN ('opened', '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 repo_id
ORDER BY stars DESC
LIMIT 10
)
SELECT
gr.repo_id,
gr.repo_name,
rws.stars
FROM repos_with_stars rws
JOIN github_repos gr USING (repo_id)
ORDER BY stars DESC
LIMIT 10




25 changes: 25 additions & 0 deletions configs/queries/orgs/repos/active/total/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"
}
]
}
43 changes: 43 additions & 0 deletions configs/queries/orgs/repos/active/total/template.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,43 @@
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 %}
), repos_per_period AS (
SELECT
-- Divide periods.
{% 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(DISTINCT repo_id) AS repos_total
FROM github_events ge
WHERE
ge.repo_id IN (SELECT repo_id FROM repos)
AND ge.type IN ('PullRequestEvent', 'PullRequestReviewEvent', 'IssuesEvent', 'IssueCommentEvent', 'PushEvent')
AND ge.action IN ('opened', 'created', '')
{% 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_repos AS (
SELECT repos_total FROM repos_per_period WHERE period = 0
), past_period_repos AS (
SELECT repos_total FROM repos_per_period WHERE period = 1
)
SELECT
cpr.repos_total AS current_period_total,
ppr.repos_total AS past_period_total,
(cpr.repos_total - ppr.repos_total) / ppr.repos_total AS growth_percentage
FROM
current_period_repos cpr,
past_period_repos ppr
;

0 comments on commit 9653dff

Please sign in to comment.