Skip to content

Commit

Permalink
feat: add prs open to merged endpoint
Browse files Browse the repository at this point in the history
  • Loading branch information
tidb-cloud-data-service[bot] authored Nov 25, 2023
1 parent c83fabc commit a1d2f51
Show file tree
Hide file tree
Showing 2 changed files with 145 additions and 7 deletions.
65 changes: 58 additions & 7 deletions configs/public_api/http_endpoints/config.json
Original file line number Diff line number Diff line change
@@ -1,7 +1,58 @@
[
{
"name": "/repos/pull_requests/open_to_mer",
"description": "",
"method": "GET",
"endpoint": "/repos/pull_requests/open_to_merge",
"data_source": {
"cluster_id": 1379661944642684098
},
"params": [
{
"name": "owner",
"type": "string",
"required": 1,
"default": "",
"description": ""
},
{
"name": "repo",
"type": "string",
"required": 1,
"default": "",
"description": ""
},
{
"name": "from",
"type": "string",
"required": 0,
"default": "2000-01-01",
"description": ""
},
{
"name": "to",
"type": "string",
"required": 0,
"default": "2099-12-31",
"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-open_to_merge.sql",
"type": "sql_endpoint",
"return_type": "json"
},
{
"name": "/repos/issues/history",
"description": "Return the p0 - p100 number of the duration between issue opened to closed (Unit: hours)",
"description": "",
"method": "GET",
"endpoint": "/repos/issues/history",
"data_source": {
Expand Down Expand Up @@ -52,7 +103,7 @@
},
{
"name": "/repos/issues/open_to_first_resp",
"description": "Return the p0 - p100 number of the duration between issue opened to closed (Unit: hours)",
"description": "Return the p0 - p100 number of the duration between issue opened to first response (comments / closed) (Unit: hours)",
"method": "GET",
"endpoint": "/repos/issues/open_to_first_responded",
"data_source": {
Expand Down Expand Up @@ -154,7 +205,7 @@
},
{
"name": "/repos/pull_reques/overview",
"description": "Returns statistics on pull request activities for a specific GitHub repository. It reports the total number of pull requests, the count of unique contributors who opened pull requests, the total number of pull request reviews, and the count of unique reviewers. ",
"description": "Returns the total number of pull requests, the count of unique contributors who opened pull requests, the total number of pull request reviews, and the count of unique reviewers. ",
"method": "GET",
"endpoint": "/repos/pull_requests/overview",
"data_source": {
Expand Down Expand Up @@ -644,7 +695,7 @@
},
{
"name": "Stargazers History",
"description": "This API provides a cumulative count of unique stargazers over a specified time period for a specific GitHub repository. It offers options to aggregate data on a daily, weekly, or monthly basis. The output includes the date and the cumulative number of unique users who have starred the repository up to that date, within the defined date range.",
"description": "Returns the date and the cumulative number of unique users who have starred the repository up to that date, within the defined date range.",
"method": "GET",
"endpoint": "/repos/stargazers/history",
"data_source": {
Expand Down Expand Up @@ -702,7 +753,7 @@
},
{
"name": "List Stargazers Orgs",
"description": "This API analyzes the distribution of stargazers across organizations for a specific GitHub repository. It groups stargazers based on their organization, providing the count and percentage of stargazers from each organization within a specified date range. The API also includes an option to exclude unknown organizations and ranks the results by the number of stargazers in descending order.",
"description": "Returns the count and percentage of stargazers from each organization within a specified date range. ranks the results by the number of stargazers in descending order.",
"method": "GET",
"endpoint": "/repos/stargazers/organizations",
"data_source": {
Expand Down Expand Up @@ -818,7 +869,7 @@
},
{
"name": "Trending Repos",
"description": "Trending repos is an open source alternative to GitHub trends, which showcases recently popular open source projects in the GitHub community.\n\n☁️ Daily run on [TiDB Cloud](https://tidbcloud.com/?utm_source=ossinsight\u0026utm_medium=ossinsight_api), analyze upon dataset that has over 6 billion GitHub events.",
"description": "Return trending repos.",
"method": "GET",
"endpoint": "/trends/repos",
"data_source": {
Expand Down Expand Up @@ -907,7 +958,7 @@
},
{
"name": "List PR Creators Orgs",
"description": "It counts the distinct creators associated with each organization and calculates their proportion of the total pull requests within a specified time frame. The API can exclude creators from unknown organizations and sorts the results in descending order based on the number of pull request creators per organization.",
"description": "It counts the distinct creators associated with each organization and calculates their proportion of the total pull requests within a specified time frame. ",
"method": "GET",
"endpoint": "/repos/pull_request_creators/organizations",
"data_source": {
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,87 @@
USE gharchive_dev;

with repo AS (
SELECT repo_id
FROM github_repos
WHERE repo_name = CONCAT(${owner}, '/', ${repo})
LIMIT 1
), pr_with_merged_at AS (
SELECT
number, DATE_FORMAT(created_at, '%Y-%m-01') AS t_month, created_at AS merged_at
FROM
github_events ge
WHERE
type = 'PullRequestEvent'
-- Considering that some repositories accept the code of the contributor by closing the PR and push commit directly,
-- here is not distinguished whether it is the merged event.
-- See: https://github.com/mongodb/mongo/pulls?q=is%3Apr+is%3Aclosed
AND action = 'closed'
AND repo_id = (SELECT repo_id FROM repo)
AND created_at >= ${from}
AND created_at <= ${to}
), pr_with_opened_at AS (
SELECT
number, created_at AS opened_at
FROM
github_events ge
WHERE
type = 'PullRequestEvent'
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)
AND created_at >= ${from}
AND created_at <= ${to}
), tdiff AS (
SELECT
t_month,
(UNIX_TIMESTAMP(pwm.merged_at) - UNIX_TIMESTAMP(pwo.opened_at)) AS diff
FROM
pr_with_opened_at pwo
JOIN pr_with_merged_at pwm ON pwo.number = pwm.number AND pwm.merged_at > pwo.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
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
WHERE r = 1
ORDER BY event_month
;

0 comments on commit a1d2f51

Please sign in to comment.