diff --git a/configs/public_api/http_endpoints/config.json b/configs/public_api/http_endpoints/config.json index 0d8dd0a5cc4..3f4a9734ebf 100644 --- a/configs/public_api/http_endpoints/config.json +++ b/configs/public_api/http_endpoints/config.json @@ -1,9 +1,9 @@ [ { - "name": "/repos/issues/opened_to_closed", + "name": "/repos/issues/open-to-first-resp", "description": "Return the p0 - p100 number of the duration between issue opened to closed (Unit: hours)", "method": "GET", - "endpoint": "/repos/issues/opened_to_closed", + "endpoint": "/repos/issues/open_to_first_responded", "data_source": { "cluster_id": 1379661944642684098 }, @@ -32,7 +32,44 @@ }, "tag": "Default", "batch_operation": 0, - "sql_file": "sql/GET-repos-issues-opened_to_closed.sql", + "sql_file": "sql/GET-repos-issues-open_to_first_responded.sql", + "type": "sql_endpoint", + "return_type": "json" + }, + { + "name": "/repos/issues/open_to_closed", + "description": "Return the p0 - p100 number of the duration between issue opened to closed (Unit: hours)", + "method": "GET", + "endpoint": "/repos/issues/open_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-open_to_closed.sql", "type": "sql_endpoint", "return_type": "json" }, @@ -149,7 +186,7 @@ }, { "name": "List Hot Collections", - "description": "List Repository Collections", + "description": "Retrieve a ranked list of repository collections based on visit frequency. This endpoint returns the top 20 most visited collections within the last month, including collection IDs, names, and associated repository metrics. The results are ordered by the number of visits in descending order to highlight the most popular collections.", "method": "GET", "endpoint": "/collections/hot", "data_source": { @@ -739,7 +776,7 @@ }, { "name": "List Collection Items", - "description": "List Repositories of Specified Collection", + "description": "List Repositories with a Collection by specify collection ID.", "method": "GET", "endpoint": "/collections/repos", "data_source": { @@ -769,7 +806,7 @@ }, { "name": "List Collections", - "description": "List Repository Collections", + "description": "It returns a list of each collection's unique ID and its name.", "method": "GET", "endpoint": "/collections", "data_source": { diff --git a/configs/public_api/http_endpoints/sql/GET-repos-issues-opened_to_closed.sql b/configs/public_api/http_endpoints/sql/GET-repos-issues-open_to_closed.sql similarity index 100% rename from configs/public_api/http_endpoints/sql/GET-repos-issues-opened_to_closed.sql rename to configs/public_api/http_endpoints/sql/GET-repos-issues-open_to_closed.sql diff --git a/configs/public_api/http_endpoints/sql/GET-repos-issues-open_to_first_responded.sql b/configs/public_api/http_endpoints/sql/GET-repos-issues-open_to_first_responded.sql new file mode 100644 index 00000000000..c8d59547633 --- /dev/null +++ b/configs/public_api/http_endpoints/sql/GET-repos-issues-open_to_first_responded.sql @@ -0,0 +1,83 @@ +USE gharchive_dev; + +with repo AS ( + SELECT repo_id + FROM github_repos + WHERE repo_name = CONCAT(${owner}, '/', ${repo}) + LIMIT 1 +), issue_with_first_responded_at AS ( + SELECT + number, MIN(DATE_FORMAT(created_at, '%Y-%m-01')) AS t_month, MIN(created_at) AS first_responded_at + FROM + github_events ge + WHERE + repo_id = (SELECT repo_id FROM repo) + AND ((type = 'IssueCommentEvent' AND action = 'created') OR (type = 'IssuesEvent' AND action = 'closed')) + -- Exclude Bots + -- AND actor_login NOT LIKE '%bot%' + -- AND actor_login NOT IN (SELECT login FROM blacklist_users bu) + GROUP BY 1 +), issue_with_opened_at AS ( + SELECT + number, created_at AS opened_at + FROM + github_events ge + WHERE + type = 'IssuesEvent' + AND action = 'opened' + AND repo_id = (SELECT repo_id FROM repo) + -- Exclude Bots + -- AND actor_login NOT LIKE '%bot%' + -- AND actor_login NOT IN (SELECT login FROM blacklist_users bu) +), tdiff AS ( + SELECT + t_month, + (UNIX_TIMESTAMP(iwfr.first_responded_at) - UNIX_TIMESTAMP(iwo.opened_at)) AS diff + FROM + issue_with_opened_at iwo + JOIN issue_with_first_responded_at iwfr ON iwo.number = iwfr.number AND iwfr.first_responded_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 + tr.t_month AS event_month, + p0, + p25, + p50, + p75, + 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 +; \ No newline at end of file