Skip to content
GitLab
Explore
Sign in
Primary navigation
Search or go to…
Project
X
xpub-epmc
Manage
Activity
Members
Labels
Plan
Wiki
Code
Merge requests
0
Repository
Branches
Commits
Tags
Repository graph
Compare revisions
Snippets
Locked files
Deploy
Releases
Package Registry
Container Registry
Operate
Terraform modules
Analyze
Value stream analytics
Contributor analytics
Repository analytics
Code review analytics
Insights
Help
Help
Support
GitLab documentation
Compare GitLab plans
Community forum
Contribute to GitLab
Provide feedback
Terms and privacy
Keyboard shortcuts
?
Snippets
Groups
Projects
Show more breadcrumbs
Literature-services
public-projects
xpub-epmc
Commits
d05e15ea
Commit
d05e15ea
authored
3 years ago
by
Audrey Hamelers
Browse files
Options
Downloads
Patches
Plain Diff
exclude weekends from tag_in_3_days count
parent
d1c12a4a
No related branches found
Branches containing commit
No related tags found
Tags containing commit
1 merge request
!391
Metrics and reviewer bug
Changes
1
Hide whitespace changes
Inline
Side-by-side
Showing
1 changed file
server/xpub-model/entities/audit/data-access.js
+25
-21
25 additions, 21 deletions
server/xpub-model/entities/audit/data-access.js
with
25 additions
and
21 deletions
server/xpub-model/entities/audit/data-access.js
+
25
−
21
View file @
d05e15ea
...
@@ -114,27 +114,31 @@ with audits as (
...
@@ -114,27 +114,31 @@ with audits as (
and ae.changes->>'status' in ('xml-review', 'xml-triage', 'repo-ready')
and ae.changes->>'status' in ('xml-review', 'xml-triage', 'repo-ready')
and ae.original_data->>'status' = 'xml-qa'
and ae.original_data->>'status' = 'xml-qa'
), taggers as (
), taggers as (
select
aa.
manuscript_id,
aa.
manuscript_version,
aa.
created,
ab.sent
select manuscript_id, manuscript_version,
sent,
created,
sum(case when extract ('ISODOW' from date_range) < 6 then 1 else 0 end) as diff
from (
from (
select at.manuscript_id, at.manuscript_version, min(at.created) created from audits at
select aa.manuscript_id, aa.manuscript_version, ab.sent, aa.created, generate_series(ab.sent, aa.created - interval '1 day', '1 day'::interval) as date_range
where at.user_id in (
from (
select user_id from team t where t.role_name='tagger'
select at.manuscript_id, at.manuscript_version, min(at.created) created from audits at
)
where at.user_id in (
and at.changes->>'type' = 'PMC'
select user_id from team t where t.role_name='tagger'
group by at.manuscript_id, at.manuscript_version
)
union
and at.changes->>'type' = 'PMC'
select a.manuscript_id, a.manuscript_version, a.created created from audits a
group by at.manuscript_id, at.manuscript_version
where a.user_id in (
union
select user_id from team t where t.role_name='admin'
select a.manuscript_id, a.manuscript_version, a.created created from audits a
)
where a.user_id in (
and a.changes::text ~* '(re-|re)tag'
select user_id from team t where t.role_name='admin'
and a.changes->>'notes_type'='userMessage'
)
) aa join (
and a.changes::text ~* '(re-|re)tag'
select att.manuscript_id, att.manuscript_version, min(att.created) sent from audits att
and a.changes->>'notes_type'='userMessage'
where att.changes->>'status' = 'tagging' and att.original_data->>'status' = 'submitted'
) aa join (
group by att.manuscript_id, att.manuscript_version
select att.manuscript_id, att.manuscript_version, min(att.created) sent from audits att
) ab on
where att.changes->>'status' = 'tagging' and att.original_data->>'status' = 'submitted'
aa.manuscript_id = ab.manuscript_id and aa.manuscript_version = ab.manuscript_version
group by att.manuscript_id, att.manuscript_version
) ab on
aa.manuscript_id = ab.manuscript_id and aa.manuscript_version = ab.manuscript_version
) t
group by manuscript_id, manuscript_version, sent, created
)
)
select display_mth, submitted, xml_review, xml_review_within_10_days,
select display_mth, submitted, xml_review, xml_review_within_10_days,
CASE WHEN xml_review=0 THEN 0 ELSE xml_review_within_10_days*100/xml_review END xml_review_within_10_days_perc,
CASE WHEN xml_review=0 THEN 0 ELSE xml_review_within_10_days*100/xml_review END xml_review_within_10_days_perc,
...
@@ -167,7 +171,7 @@ full outer join (
...
@@ -167,7 +171,7 @@ full outer join (
) qa on top.mth = qa.mth
) qa on top.mth = qa.mth
full outer join (
full outer join (
select TO_CHAR(date_trunc('month', tag.created AT TIME ZONE 'Europe/London') , 'YYYYMM') mth, count(*) xml_tagging,
select TO_CHAR(date_trunc('month', tag.created AT TIME ZONE 'Europe/London') , 'YYYYMM') mth, count(*) xml_tagging,
SUM(CASE WHEN
DATE_PART('DAY', tag.created-tag.sent)
< 4 THEN 1 ELSE 0 END) xml_tagging_within_3_days
SUM(CASE WHEN
tag.diff
< 4 THEN 1 ELSE 0 END) xml_tagging_within_3_days
from taggers tag
from taggers tag
group by mth
group by mth
) tagging on top.mth = tagging.mth
) tagging on top.mth = tagging.mth
...
...
This diff is collapsed.
Click to expand it.
Preview
0%
Try again
or
attach a new file
.
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Save comment
Cancel
Please
register
or
sign in
to comment