Skip to content

Commit

Permalink
materialized view and docs update
Browse files Browse the repository at this point in the history
  • Loading branch information
cdolfi authored and JamesKunstle committed Sep 29, 2023
1 parent 9fcc4b1 commit e00540b
Show file tree
Hide file tree
Showing 7 changed files with 150 additions and 168 deletions.
2 changes: 1 addition & 1 deletion 8Knot/queries/contributors_query.py
Original file line number Diff line number Diff line change
Expand Up @@ -24,7 +24,7 @@ def contributors_query(self, repos):
Explorer_contributor_actions is a materialized view on the database for quicker run time and
may not be in your augur database. The SQL query content can be found
in docs/explorer_contributor_actions.sql
in docs/materialized_views/explorer_contributor_actions.sql
Args:
-----
Expand Down
22 changes: 8 additions & 14 deletions 8Knot/queries/issue_assignee_query.py
Original file line number Diff line number Diff line change
Expand Up @@ -22,6 +22,10 @@ def issue_assignee_query(self, repos):
(Worker Query)
Executes SQL query against Augur database for contributor data.
Explorer_issue_assignments is a materialized view on the database for quicker run time and
may not be in your augur database. The SQL query content can be found
in docs/materialized_views/explorer_issue_assignments.sql
Args:
-----
repo_ids ([str]): repos that SQL query is executed on.
Expand All @@ -36,21 +40,11 @@ def issue_assignee_query(self, repos):

query_string = f"""
SELECT
i.issue_id,
i.repo_id AS id,
i.created_at as created,
i.closed_at as closed,
ie.created_at AS assign_date,
ie.action AS assignment_action,
ie.cntrb_id AS assignee
*
FROM
issues i
LEFT OUTER JOIN
issue_events ie
ON
i.issue_id = ie.issue_id AND
ie.action IN ('unassigned', 'assigned') AND
i.repo_id IN ({str(repos)[1:-1]})
explorer_issue_assignments
WHERE
repo_id in ({str(repos)[1:-1]})
"""

try:
Expand Down
22 changes: 8 additions & 14 deletions 8Knot/queries/pr_assignee_query.py
Original file line number Diff line number Diff line change
Expand Up @@ -22,6 +22,10 @@ def pr_assignee_query(self, repos):
(Worker Query)
Executes SQL query against Augur database for contributor data.
Explorer_pr_assignments is a materialized view on the database for quicker run time and
may not be in your augur database. The SQL query content can be found
in docs/materialized_views/explorer_pr_assignments.sql
Args:
-----
repo_ids ([str]): repos that SQL query is executed on.
Expand All @@ -36,21 +40,11 @@ def pr_assignee_query(self, repos):

query_string = f"""
SELECT
pr.pull_request_id,
pr.repo_id AS id,
pr.pr_created_at AS created,
pr.pr_closed_at as closed,
pre.created_at AS assign_date,
pre.action AS assignment_action,
pre.cntrb_id AS assignee
*
FROM
pull_requests pr
LEFT OUTER JOIN
pull_request_events pre
ON
pr.pull_request_id = pre.pull_request_id AND
pre.action IN ('unassigned', 'assigned') AND
pr.repo_id in ({str(repos)[1:-1]})
explorer_pr_assignments
WHERE
repo_id in ({str(repos)[1:-1]})
"""

try:
Expand Down
139 changes: 0 additions & 139 deletions docs/explorer_contributor_actions.sql

This file was deleted.

99 changes: 99 additions & 0 deletions docs/materialized_views/explorer_contributor_actions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,99 @@
/* This is the SQL query that populates the explorer_contributor_actions materialized view*/

SELECT a.id AS cntrb_id,
a.created_at,
a.repo_id,
a.action,
repo.repo_name,
a.login,
row_number() OVER (PARTITION BY a.id, a.repo_id ORDER BY a.created_at DESC) AS rank
FROM ( SELECT commits.cmt_ght_author_id AS id,
commits.cmt_author_timestamp AS created_at,
commits.repo_id,
'commit'::text AS action,
contributors.cntrb_login AS login
FROM (augur_data.commits
LEFT JOIN augur_data.contributors ON (((contributors.cntrb_id)::text = (commits.cmt_ght_author_id)::text)))
GROUP BY commits.cmt_commit_hash, commits.cmt_ght_author_id, commits.repo_id, commits.cmt_author_timestamp, 'commit'::text, contributors.cntrb_login
UNION ALL
SELECT issues.reporter_id AS id,
issues.created_at,
issues.repo_id,
'issue_opened'::text AS action,
contributors.cntrb_login AS login
FROM (augur_data.issues
LEFT JOIN augur_data.contributors ON ((contributors.cntrb_id = issues.reporter_id)))
WHERE (issues.pull_request IS NULL)
UNION ALL
SELECT pull_request_events.cntrb_id AS id,
pull_request_events.created_at,
pull_requests.repo_id,
'pull_request_closed'::text AS action,
contributors.cntrb_login AS login
FROM augur_data.pull_requests,
(augur_data.pull_request_events
LEFT JOIN augur_data.contributors ON ((contributors.cntrb_id = pull_request_events.cntrb_id)))
WHERE ((pull_requests.pull_request_id = pull_request_events.pull_request_id) AND (pull_requests.pr_merged_at IS NULL) AND ((pull_request_events.action)::text = 'closed'::text))
UNION ALL
SELECT pull_request_events.cntrb_id AS id,
pull_request_events.created_at,
pull_requests.repo_id,
'pull_request_merged'::text AS action,
contributors.cntrb_login AS login
FROM augur_data.pull_requests,
(augur_data.pull_request_events
LEFT JOIN augur_data.contributors ON ((contributors.cntrb_id = pull_request_events.cntrb_id)))
WHERE ((pull_requests.pull_request_id = pull_request_events.pull_request_id) AND ((pull_request_events.action)::text = 'merged'::text))
UNION ALL
SELECT issue_events.cntrb_id AS id,
issue_events.created_at,
issues.repo_id,
'issue_closed'::text AS action,
contributors.cntrb_login AS login
FROM augur_data.issues,
(augur_data.issue_events
LEFT JOIN augur_data.contributors ON ((contributors.cntrb_id = issue_events.cntrb_id)))
WHERE ((issues.issue_id = issue_events.issue_id) AND (issues.pull_request IS NULL) AND ((issue_events.action)::text = 'closed'::text))
UNION ALL
SELECT pull_request_reviews.cntrb_id AS id,
pull_request_reviews.pr_review_submitted_at AS created_at,
pull_requests.repo_id,
('pull_request_review_'::text || (pull_request_reviews.pr_review_state)::text) AS action,
contributors.cntrb_login AS login
FROM augur_data.pull_requests,
(augur_data.pull_request_reviews
LEFT JOIN augur_data.contributors ON ((contributors.cntrb_id = pull_request_reviews.cntrb_id)))
WHERE (pull_requests.pull_request_id = pull_request_reviews.pull_request_id)
UNION ALL
SELECT pull_requests.pr_augur_contributor_id AS id,
pull_requests.pr_created_at AS created_at,
pull_requests.repo_id,
'pull_request_open'::text AS action,
contributors.cntrb_login AS login
FROM (augur_data.pull_requests
LEFT JOIN augur_data.contributors ON ((pull_requests.pr_augur_contributor_id = contributors.cntrb_id)))
UNION ALL
SELECT message.cntrb_id AS id,
message.msg_timestamp AS created_at,
pull_requests.repo_id,
'pull_request_comment'::text AS action,
contributors.cntrb_login AS login
FROM augur_data.pull_requests,
augur_data.pull_request_message_ref,
(augur_data.message
LEFT JOIN augur_data.contributors ON ((contributors.cntrb_id = message.cntrb_id)))
WHERE ((pull_request_message_ref.pull_request_id = pull_requests.pull_request_id) AND (pull_request_message_ref.msg_id = message.msg_id))
UNION ALL
SELECT issues.reporter_id AS id,
message.msg_timestamp AS created_at,
issues.repo_id,
'issue_comment'::text AS action,
contributors.cntrb_login AS login
FROM augur_data.issues,
augur_data.issue_message_ref,
(augur_data.message
LEFT JOIN augur_data.contributors ON ((contributors.cntrb_id = message.cntrb_id)))
WHERE ((issue_message_ref.msg_id = message.msg_id) AND (issues.issue_id = issue_message_ref.issue_id) AND (issues.closed_at <> message.msg_timestamp))) a,
augur_data.repo
WHERE (a.repo_id = repo.repo_id)
ORDER BY a.created_at DESC
17 changes: 17 additions & 0 deletions docs/materialized_views/explorer_issue_assignments.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
/* This is the SQL query that populates the explorer_issue_assignments materialized view*/

SELECT
i.issue_id,
i.repo_id AS id,
i.created_at as created,
i.closed_at as closed,
ie.created_at AS assign_date,
ie.action AS assignment_action,
ie.cntrb_id AS assignee
FROM
issues i
LEFT OUTER JOIN
issue_events ie
ON
i.issue_id = ie.issue_id AND
ie.action IN ('unassigned', 'assigned')
17 changes: 17 additions & 0 deletions docs/materialized_views/explorer_pr_assignments.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
/* This is the SQL query that populates the explorer_pr_assignments materialized view*/

SELECT
pr.pull_request_id,
pr.repo_id AS id,
pr.pr_created_at AS created,
pr.pr_closed_at as closed,
pre.created_at AS assign_date,
pre.action AS assignment_action,
pre.cntrb_id AS assignee
FROM
pull_requests pr
LEFT OUTER JOIN
pull_request_events pre
ON
pr.pull_request_id = pre.pull_request_id AND
pre.action IN ('unassigned', 'assigned')

0 comments on commit e00540b

Please sign in to comment.