Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

queries: add analyze recent contributors query #1584

Merged
merged 3 commits into from
Aug 14, 2023
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
6 changes: 4 additions & 2 deletions .github/workflows/verify-query.yml
Original file line number Diff line number Diff line change
Expand Up @@ -4,11 +4,12 @@ on:
pull_request:
paths:
- 'configs/queries/**'
- 'packages/types/**'

defaults:
run:
shell: bash
working-directory: packages/api-server
working-directory: packages/types

jobs:
validate:
Expand Down Expand Up @@ -40,10 +41,11 @@ jobs:
name: Setup pnpm cache
with:
path: ${{ steps.pnpm-cache.outputs.STORE_PATH }}
key: ${{ runner.os }}-pnpm-store-${{ hashFiles('**/pnpm-lock.yaml') }}
key: ${{ runner.os }}-pnpm-store-${{ hashFiles('./pnpm-lock.yaml') }}
restore-keys: |
${{ runner.os }}-pnpm-store-


- name: Install Dependencies
run: pnpm i --frozen-lockfile --strict-peer-dependencies

Expand Down
10 changes: 10 additions & 0 deletions configs/queries/analyze-recent-contributors/params.json
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
{
"cacheHours": 1,
"params": [
{
"name": "repoId",
"replaces": "41986369",
"pattern": "^[1-9]\\d*$"
}
]
}
91 changes: 91 additions & 0 deletions configs/queries/analyze-recent-contributors/template.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,91 @@
WITH RECURSIVE seq(idx, current_period_day, last_period_day) AS (
SELECT
1 AS idx,
CURRENT_DATE() AS current_period_day,
DATE_SUB(CURRENT_DATE(), INTERVAL 28 day) AS last_period_day
UNION ALL
SELECT
idx + 1 AS idx,
DATE_SUB(CURRENT_DATE(), INTERVAL idx day) AS current_period_day,
DATE_SUB(CURRENT_DATE(), INTERVAL idx + 28 day) AS last_period_day
FROM seq
WHERE idx < 28
), group_by_day AS (
SELECT
day_offset % 28 + 1 AS idx,
day_offset DIV 28 AS period,
day,
contributors
FROM (
SELECT
(DATEDIFF(CURRENT_DATE(), day)) AS day_offset,
day,
contributors
FROM (
SELECT
DATE_FORMAT(created_at, '%Y-%m-%d') AS day,
COUNT(DISTINCT actor_id) AS contributors
FROM
github_events ge
WHERE
repo_id = 41986369
AND (
(type = 'PullRequestEvent' AND action = 'opened') OR
(type = 'IssuesEvent' AND action = 'opened') OR
(type = 'IssueCommentEvent' AND action = 'created') OR
(type = 'PullRequestReviewEvent' AND action = 'created') OR
(type = 'PullRequestReviewCommentEvent' AND action = 'created') OR
(type = 'PushEvent' AND action = '')
)
AND created_at > DATE_SUB(CURRENT_DATE(), INTERVAL 56 DAY)
GROUP BY day
ORDER BY day
) sub
) sub2
), group_by_period AS (
SELECT
(DATEDIFF(CURRENT_DATE(), created_at)) DIV 28 AS period,
COUNT(DISTINCT actor_id) AS contributors
FROM
github_events ge
WHERE
repo_id = 41986369
AND (
(type = 'PullRequestEvent' AND action = 'opened') OR
(type = 'IssuesEvent' AND action = 'opened') OR
(type = 'IssueCommentEvent' AND action = 'created') OR
(type = 'PullRequestReviewEvent' AND action = 'created') OR
(type = 'PullRequestReviewCommentEvent' AND action = 'created') OR
(type = 'PushEvent' AND action = '')
)
AND created_at > DATE_SUB(CURRENT_DATE(), INTERVAL 56 DAY)
GROUP BY period
ORDER BY period
), last_28_days AS (
SELECT idx, day, contributors
FROM group_by_day
WHERE period = 0
), last_2nd_28_days AS (
SELECT idx, day, contributors
FROM group_by_day
WHERE period = 1
), last_28_days_total AS (
SELECT contributors AS total FROM group_by_period WHERE period = 0
), last_2nd_28_days_total AS (
SELECT contributors AS total FROM group_by_period WHERE period = 1
)
SELECT
s.idx AS idx,
s.current_period_day AS current_period_day,
IFNULL(cp.contributors, 0) AS current_period_day_contributors,
IFNULL(cpt.total, 0) AS current_period_contributors,
s.last_period_day AS last_period_day,
IFNULL(lp.contributors, 0) AS last_period_day_contributors,
IFNULL(lpt.total, 0) AS last_period_contributors
FROM seq s
LEFT JOIN last_28_days cp ON s.idx = cp.idx
LEFT JOIN last_2nd_28_days lp ON s.idx = lp.idx
JOIN last_28_days_total cpt
JOIN last_2nd_28_days_total lpt
ORDER BY idx
;
38 changes: 21 additions & 17 deletions configs/queries/events-increment-list/template.sql
Original file line number Diff line number Diff line change
@@ -1,18 +1,22 @@
SELECT
/*+ MAX_EXECUTION_TIME(15000) */
id, type, action, actor_id, actor_login, repo_id, repo_name, number, pr_merged, created_at
FROM github_events
WHERE
created_at BETWEEN (
UTC_TIMESTAMP - INTERVAL 6 MINUTE - INTERVAL UNIX_TIMESTAMP(UTC_TIMESTAMP - INTERVAL 6 MINUTE) % 5 SECOND
) AND (
UTC_TIMESTAMP - INTERVAL 5 MINUTE - INTERVAL UNIX_TIMESTAMP(UTC_TIMESTAMP - INTERVAL 5 MINUTE) % 5 SECOND
)
AND actor_login NOT LIKE '%[bot]'
AND actor_login NOT LIKE '%-bot'
AND type IN (
'WatchEvent', 'ForkEvent', 'IssuesEvent', 'PullRequestEvent', 'PushEvent', 'CreateEvent', 'ReleaseEvent',
'PullRequestReviewCommentEvent', 'PullRequestReviewEvent', 'IssueCommentEvent'
)
SELECT *
FROM (
SELECT
/*+ READ_FROM_STORAGE(TIKV[github_events]), MAX_EXECUTION_TIME(15000) */
id, type, action, actor_id, actor_login, repo_id, repo_name, number, pr_merged, created_at
FROM github_events
WHERE
created_at BETWEEN (
UTC_TIMESTAMP - INTERVAL 6 MINUTE - INTERVAL UNIX_TIMESTAMP(UTC_TIMESTAMP - INTERVAL 6 MINUTE) % 5 SECOND
) AND (
UTC_TIMESTAMP - INTERVAL 5 MINUTE - INTERVAL UNIX_TIMESTAMP(UTC_TIMESTAMP - INTERVAL 5 MINUTE) % 5 SECOND
)
AND actor_login NOT LIKE '%[bot]'
AND actor_login NOT LIKE '%-bot'
AND type IN (
'WatchEvent', 'ForkEvent', 'IssuesEvent', 'PullRequestEvent', 'PushEvent', 'CreateEvent', 'ReleaseEvent',
'PullRequestReviewCommentEvent', 'PullRequestReviewEvent', 'IssueCommentEvent'
)
LIMIT 50
) sub
ORDER BY created_at DESC
LIMIT 50;
;
15 changes: 8 additions & 7 deletions configs/queries/recent-hot-collections/template.sql
Original file line number Diff line number Diff line change
@@ -1,13 +1,13 @@
WITH collectionsOrderByVisits AS (
SELECT
CAST(JSON_EXTRACT(request_params, '$.collectionId') AS SIGNED) AS collection_id,
CAST(JSON_EXTRACT(query, '$.collectionId') AS SIGNED) AS collection_id,
COUNT(*) AS visits
FROM access_logs
FROM stats_api_requests
WHERE
request_path LIKE '/q/collection-%'
AND requested_at > DATE_SUB(NOW(), INTERVAL 1 MONTH)
GROUP BY 1
ORDER BY 2 DESC
path LIKE '/q/collection-%'
AND finished_at > DATE_SUB(NOW(), INTERVAL 1 MONTH)
GROUP BY collection_id
ORDER BY visits DESC
), top10collections AS (
SELECT c.id, c.name, cv.visits
FROM collectionsOrderByVisits cv
Expand All @@ -29,4 +29,5 @@ FROM (
FROM collection_items ci
JOIN top10collections tc ON ci.collection_id = tc.id
) sub
WHERE `rank` <= 3;
WHERE `rank` <= 3
ORDER BY visits DESC;
2 changes: 0 additions & 2 deletions packages/api-server/package.json
Original file line number Diff line number Diff line change
Expand Up @@ -9,8 +9,6 @@
"test": "__tests__"
},
"scripts": {
"gen:schema-ts": "json2ts ./schema/query.schema.json ./src/types/query.schema.d.ts",
"validate:query": "ajv -s ./schema/query.schema.json -r ./schema/openapi-2021-09-28.schema.json -c ajv-formats -d \"../../configs/queries/*/params.json\"",
"build:ts": "tsc",
"dev": "NODE_ENV=development fastify start -p ${API_SERVER_PORT:-3450} -P --ignore-watch=.ts$ -L dist/logger.js -l info -w dist/app.js",
"build": "rm -rf dist && npm run build:ts",
Expand Down
Loading