Skip to content

Commit

Permalink
public-api: add repo overview APIs
Browse files Browse the repository at this point in the history
  • Loading branch information
tidb-cloud-data-service[bot] authored Nov 24, 2023
1 parent c934452 commit 681cb56
Show file tree
Hide file tree
Showing 5 changed files with 374 additions and 0 deletions.
148 changes: 148 additions & 0 deletions configs/public_api/http_endpoints/config.json
Original file line number Diff line number Diff line change
@@ -1,4 +1,152 @@
[
{
"name": "/repos/issues/opened_to_closed",
"description": "Return the p0 - p100 number of the duration between issue opened to closed (Unit: hours)",
"method": "GET",
"endpoint": "/repos/issues/opened_to_closed",
"data_source": {
"cluster_id": 1379661944642684098
},
"params": [
{
"name": "owner",
"type": "string",
"required": 1,
"default": "",
"description": ""
},
{
"name": "repo",
"type": "string",
"required": 1,
"default": "",
"description": ""
}
],
"settings": {
"timeout": 30000,
"row_limit": 1000,
"cache_enabled": 1,
"cache_ttl": 600,
"enable_pagination": 0
},
"tag": "Default",
"batch_operation": 0,
"sql_file": "sql/GET-repos-issues-opened_to_closed.sql",
"type": "sql_endpoint",
"return_type": "json"
},
{
"name": "/repos/pull_reques/overview",
"description": "",
"method": "GET",
"endpoint": "/repos/pull_requests/overview",
"data_source": {
"cluster_id": 1379661944642684098
},
"params": [
{
"name": "owner",
"type": "string",
"required": 1,
"default": "",
"description": ""
},
{
"name": "repo",
"type": "string",
"required": 1,
"default": "",
"description": ""
}
],
"settings": {
"timeout": 30000,
"row_limit": 1000,
"cache_enabled": 1,
"cache_ttl": 600,
"enable_pagination": 0
},
"tag": "Default",
"batch_operation": 0,
"sql_file": "sql/GET-repos-pull_requests-overview.sql",
"type": "sql_endpoint",
"return_type": "json"
},
{
"name": "/repos/issues/overview",
"description": "",
"method": "GET",
"endpoint": "/repos/issues/overview",
"data_source": {
"cluster_id": 1379661944642684098
},
"params": [
{
"name": "owner",
"type": "string",
"required": 1,
"default": "",
"description": ""
},
{
"name": "repo",
"type": "string",
"required": 1,
"default": "",
"description": ""
}
],
"settings": {
"timeout": 30000,
"row_limit": 1000,
"cache_enabled": 1,
"cache_ttl": 600,
"enable_pagination": 0
},
"tag": "Default",
"batch_operation": 0,
"sql_file": "sql/GET-repos-issues-overview.sql",
"type": "sql_endpoint",
"return_type": "json"
},
{
"name": "/repos/overview",
"description": "",
"method": "GET",
"endpoint": "/repos/overview",
"data_source": {
"cluster_id": 1379661944642684098
},
"params": [
{
"name": "owner",
"type": "string",
"required": 1,
"default": "",
"description": ""
},
{
"name": "repo",
"type": "string",
"required": 1,
"default": "",
"description": ""
}
],
"settings": {
"timeout": 30000,
"row_limit": 1000,
"cache_enabled": 1,
"cache_ttl": 600,
"enable_pagination": 0
},
"tag": "Default",
"batch_operation": 0,
"sql_file": "sql/GET-repos-overview.sql",
"type": "sql_endpoint",
"return_type": "json"
},
{
"name": "List Hot Collections",
"description": "List Repository Collections",
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,79 @@
USE gharchive_dev;

with repo AS (
SELECT repo_id
FROM github_repos
WHERE repo_name = CONCAT(${owner}, '/', ${repo})
LIMIT 1
), issue_with_closed_at as (
select
number, DATE_FORMAT(created_at, '%Y-%m-01') AS t_month, created_at as closed_at
from
github_events ge
where
type = 'IssuesEvent'
and action = 'closed'
and repo_id = (SELECT repo_id FROM repo)
), issue_with_opened_at as (
select
number, created_at as opened_at
from
github_events ge
where
type = 'IssuesEvent'
and action = 'opened'
-- Exclude Bots
-- and actor_login not like '%bot%'
-- and actor_login not in (select login from blacklist_users bu)
and repo_id = (SELECT repo_id FROM repo)
), tdiff as (
select
DATE_FORMAT(t_month, '%Y-%m-01') AS t_month,
(UNIX_TIMESTAMP(iwc.closed_at) - UNIX_TIMESTAMP(iwo.opened_at)) as diff
from
issue_with_opened_at iwo
join issue_with_closed_at iwc on iwo.number = iwc.number and iwc.closed_at > iwo.opened_at
), tdiff_with_rank as (
select
tdiff.t_month,
diff / 60 / 60 as diff,
ROW_NUMBER() over (partition by tdiff.t_month order by diff) as r,
count(*) over (partition by tdiff.t_month) as cnt,
first_value(diff / 60 / 60) over (partition by tdiff.t_month order by diff) as p0,
first_value(diff / 60 / 60) over (partition by tdiff.t_month order by diff desc) as p100
from tdiff
), tdiff_p25 as (
select
t_month, diff as p25
from
tdiff_with_rank tr
where
r = round(cnt * 0.25)
), tdiff_p50 as (
select
t_month, diff as p50
from
tdiff_with_rank tr
where
r = round(cnt * 0.5)
), tdiff_p75 as (
select
t_month, diff as p75
from
tdiff_with_rank tr
where
r = round(cnt * 0.75)
)
select
distinct tr.t_month AS event_month,
ROUND(p0, 2) AS p0,
ROUND(p25, 2) AS p25,
ROUND(p50, 2) AS p50,
ROUND(p75, 2) AS p75,
ROUND(p100, 2) AS p100
from tdiff_with_rank tr
left join tdiff_p25 p25 on tr.t_month = p25.t_month
left join tdiff_p50 p50 on tr.t_month = p50.t_month
left join tdiff_p75 p75 on tr.t_month = p75.t_month
order by 1
;
Original file line number Diff line number Diff line change
@@ -0,0 +1,50 @@
USE gharchive_dev;
WITH repo AS (
SELECT repo_id
FROM github_repos
WHERE repo_name = CONCAT(${owner}, '/', ${repo})
LIMIT 1
), issues AS (
SELECT
COUNT(*) AS total
FROM github_events
WHERE
repo_id = (SELECT repo_id FROM repo)
AND type = 'IssuesEvent'
AND action = 'opened'
), issue_creators AS (
SELECT
COUNT(DISTINCT actor_login) AS total
FROM github_events
WHERE
repo_id = (SELECT repo_id FROM repo)
AND type = 'IssuesEvent'
AND action = 'opened'
), issue_comments AS (
SELECT
COUNT(*) AS total
FROM github_events
WHERE
repo_id = (SELECT repo_id FROM repo)
AND type = 'IssueCommentEvent'
AND action = 'created'
), issue_commenters AS (
SELECT
COUNT(DISTINCT actor_login) AS total
FROM github_events
WHERE
repo_id = (SELECT repo_id FROM repo)
AND type = 'IssueCommentEvent'
AND action = 'created'
)
SELECT
IFNULL(i.total, 0) AS issues,
IFNULL(ic.total, 0) AS issue_creators,
IFNULL(ico.total, 0) AS issue_comments,
IFNULL(icc.total, 0) AS issue_commenters
FROM repo r
LEFT JOIN issues i ON 1 = 1
LEFT JOIN issue_creators ic ON 1 = 1
LEFT JOIN issue_comments ico ON 1 = 1
LEFT JOIN issue_commenters icc ON 1 = 1
;
48 changes: 48 additions & 0 deletions configs/public_api/http_endpoints/sql/GET-repos-overview.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,48 @@
USE gharchive_dev;
WITH repo AS (
SELECT repo_id
FROM github_repos
WHERE repo_name = CONCAT(${owner}, '/', ${repo})
LIMIT 1
), stars AS (
SELECT
IFNULL(COUNT(DISTINCT actor_login), 0) AS total
FROM github_events
WHERE
type = 'WatchEvent'
AND repo_id = (SELECT repo_id FROM repo)
AND action = 'started'
), commits AS (
SELECT
IFNULL(SUM(push_distinct_size), 0) AS total
FROM github_events
WHERE
type = 'PushEvent'
AND repo_id = (SELECT repo_id FROM repo)
), issues AS (
SELECT
IFNULL(COUNT(DISTINCT number), 0) AS total
FROM github_events
WHERE
type = 'IssuesEvent'
AND repo_id = (SELECT repo_id FROM repo)
), pull_request_creators AS (
SELECT
IFNULL(COUNT(DISTINCT actor_login), 0) AS total
FROM github_events
WHERE
type = 'PullRequestEvent'
AND repo_id = (SELECT repo_id FROM repo)
AND action = 'opened'
)
SELECT
s.total AS stars,
c.total AS commits,
i.total AS issues,
prc.total AS pull_request_creators
FROM repo r
LEFT JOIN stars s ON 1 = 1
LEFT JOIN commits c ON 1 = 1
LEFT JOIN issues i ON 1 = 1
LEFT JOIN pull_request_creators prc ON 1 = 1
;
Original file line number Diff line number Diff line change
@@ -0,0 +1,49 @@
USE gharchive_dev;
WITH repo AS (
SELECT repo_id
FROM github_repos
WHERE repo_name = CONCAT(${owner}, '/', ${repo})
LIMIT 1
), pull_requests AS (
SELECT
IFNULL(COUNT(DISTINCT number), 0) AS total
FROM github_events
WHERE
type = 'PullRequestEvent'
AND repo_id = (SELECT repo_id FROM repo)
), pull_request_creators AS (
SELECT
IFNULL(COUNT(DISTINCT actor_login), 0) AS total
FROM github_events
WHERE
type = 'PullRequestEvent'
AND action = 'opened'
AND repo_id = (SELECT repo_id FROM repo)
), pull_request_reviews AS (
SELECT
IFNULL(COUNT(1), 0) AS total
FROM github_events
WHERE
type = 'PullRequestReviewEvent'
AND action = 'created'
AND repo_id = (SELECT repo_id FROM repo)
), pull_request_reviewers AS (
SELECT
IFNULL(COUNT(DISTINCT actor_login), 0) AS total
FROM github_events
WHERE
type = 'PullRequestReviewEvent'
AND action = 'created'
AND repo_id = (SELECT repo_id FROM repo)
)
SELECT
pr.total AS pull_requests,
prc.total AS pull_request_creators,
prr.total AS pull_request_reviews,
prrc.total AS pull_request_reviewers
FROM repo r
LEFT JOIN pull_requests pr ON 1 = 1
LEFT JOIN pull_request_creators prc ON 1 = 1
LEFT JOIN pull_request_reviews prr ON 1 = 1
LEFT JOIN pull_request_reviewers prrc ON 1 = 1
;

0 comments on commit 681cb56

Please sign in to comment.