-
Notifications
You must be signed in to change notification settings - Fork 9
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge pull request #109 from nikmagini/submissiontool
Add new MViews to exlcude production jobs from PopDB queries New CRAB PopDB version including: 1) DB schema changes: add new MViews in which wmagent file accesses are filtered out 2) DB collector changes: add new MViews to MView refresh script 3) Web changes: new 'includewmagent' parameter to toggle between old MViews (including WMAgent file accesses) and new MViews (excluding WMAgent). Default value is 'n'
- Loading branch information
Showing
9 changed files
with
310 additions
and
16 deletions.
There are no files selected for viewing
134 changes: 134 additions & 0 deletions
134
DataPopularity/popdb.crab/collector/config/db/CreateMVDSStat1.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,134 @@ | ||
--- aggregation: day, sitename, dataset | ||
--- exclude production | ||
--- count distinct users per day, aggregating later more days will | ||
--- double count the same users that submitted in several days | ||
|
||
CREATE MATERIALIZED VIEW MV_DS_stat1_aggr1 | ||
COMPRESS | ||
PCTFREE 0 | ||
BUILD IMMEDIATE | ||
ENABLE QUERY REWRITE | ||
AS | ||
select TDay , siteName, collName, | ||
sum(numAccesses) as numAccesses, sum(totCPU) as totCPU, count(distinct userid) as numUsers | ||
from MV_DS_stat0 | ||
where submissiontool!='wmagent' | ||
GROUP BY TDay, siteName, collName | ||
; | ||
|
||
--- aggregation: day, dataset | ||
--- exclude production | ||
--- count distinct users per day, aggregating later more days will | ||
--- double count the same users that submitted in several days | ||
|
||
CREATE MATERIALIZED VIEW MV_DS_stat1_aggr1_summ | ||
COMPRESS | ||
PCTFREE 0 | ||
BUILD IMMEDIATE | ||
ENABLE QUERY REWRITE | ||
AS | ||
select TDay , collName, | ||
sum(numAccesses) as numAccesses, sum(totCPU) as totCPU, count(distinct userid) as numUsers | ||
from MV_DS_stat0 | ||
where submissiontool!='wmagent' | ||
GROUP BY TDay, collName | ||
; | ||
|
||
--- aggregation: day, sitename, dataTier | ||
--- count distinct users per day, aggregating later more days will | ||
--- double count the same users that submitted in several days | ||
--- excludes wmagent jobs | ||
|
||
CREATE MATERIALIZED VIEW MV_DS_stat1_aggr2 | ||
COMPRESS | ||
PCTFREE 0 | ||
BUILD IMMEDIATE | ||
ENABLE QUERY REWRITE | ||
AS | ||
select TDay , siteName, substr(collName,INSTR(collName, '/',-1)+1) as collName, | ||
sum(numAccesses) as numAccesses, sum(totCPU) as totCPU, count (distinct userid) as numUsers | ||
from MV_DS_stat0 | ||
where submissiontool!='wmagent' | ||
GROUP BY TDay, siteName, substr(collName,INSTR(collName, '/',-1)+1) | ||
; | ||
|
||
|
||
--- aggregation: day, datatier | ||
--- count distinct users per day, aggregating later more days will | ||
--- double count the same users that submitted in several days | ||
--- excludes wmagent jobs | ||
|
||
CREATE MATERIALIZED VIEW MV_DS_stat1_aggr2_summ | ||
COMPRESS | ||
PCTFREE 0 | ||
BUILD IMMEDIATE | ||
ENABLE QUERY REWRITE | ||
AS | ||
select TDay , substr(collName,INSTR(collName, '/',-1)+1) as collName, | ||
sum(numAccesses) as numAccesses, sum(totCPU) as totCPU, count (distinct userid) as numUsers | ||
from MV_DS_stat0 | ||
where submissiontool!='wmagent' | ||
GROUP BY TDay, substr(collName,INSTR(collName, '/',-1)+1) | ||
; | ||
|
||
|
||
--- First aggregation: day, sitename, dataset namespace (ReReco, Summer2011, etc) | ||
--- count distinct users per day, aggregating later more days will | ||
--- double count the same users that submitted in several days | ||
--- excludes wmagent jobs | ||
|
||
CREATE MATERIALIZED VIEW MV_DS_stat1_aggr4 | ||
COMPRESS | ||
PCTFREE 0 | ||
BUILD IMMEDIATE | ||
ENABLE QUERY REWRITE | ||
AS | ||
select TDay , siteName, | ||
substr(collname,INSTR(collname, '/',-1,2)+1,INSTR(collname, '/',-1,1)-INSTR(collname, '/',-1,2)-1) as collName, | ||
sum(numAccesses) as numAccesses, sum(totCPU) as totCPU, count (distinct userid) as numUsers | ||
from MV_DS_stat0 | ||
where | ||
substr(collname,INSTR(collname, '/',-1,1)+1) not like 'USER' | ||
and | ||
collname not like 'unknown' | ||
and submissiontool!='wmagent' | ||
GROUP BY TDay, siteName, substr(collname,INSTR(collname, '/',-1,2)+1,INSTR(collname, '/',-1,1)-INSTR(collname, '/',-1,2)-1) | ||
; | ||
|
||
|
||
--- Second aggregation: day, dataset namespace (ReReco, Summer2011, etc) | ||
--- count distinct users per day, aggregating later more days will | ||
--- double count the same users that submitted in several days | ||
--- excludes wmagent jobs | ||
|
||
CREATE MATERIALIZED VIEW MV_DS_stat1_aggr4_summ | ||
COMPRESS | ||
PCTFREE 0 | ||
BUILD IMMEDIATE | ||
ENABLE QUERY REWRITE | ||
AS | ||
select TDay , | ||
substr(collname,INSTR(collname, '/',-1,2)+1,INSTR(collname, '/',-1,1)-INSTR(collname, '/',-1,2)-1) as collName, | ||
sum(numAccesses) as numAccesses, sum(totCPU) as totCPU, count (distinct userid) as numUsers | ||
from MV_DS_stat0 | ||
where | ||
substr(collname,INSTR(collname, '/',-1,1)+1) not like 'USER' | ||
and | ||
collname not like 'unknown' | ||
and submissiontool!='wmagent' | ||
GROUP BY TDay, substr(collname,INSTR(collname, '/',-1,2)+1,INSTR(collname, '/',-1,1)-INSTR(collname, '/',-1,2)-1) | ||
; | ||
|
||
grant select on MV_DS_STAT1_AGGR1 to CMS_POPULARITY_SYSTEM_R; | ||
grant select on MV_DS_STAT1_AGGR1_SUMM to CMS_POPULARITY_SYSTEM_R; | ||
grant select on MV_DS_STAT1_AGGR2 to CMS_POPULARITY_SYSTEM_R; | ||
grant select on MV_DS_STAT1_AGGR2_SUMM to CMS_POPULARITY_SYSTEM_R; | ||
grant select on MV_DS_STAT1_AGGR4 to CMS_POPULARITY_SYSTEM_R; | ||
grant select on MV_DS_STAT1_AGGR4_SUMM to CMS_POPULARITY_SYSTEM_R; | ||
|
||
grant select, insert, update, delete on MV_DS_STAT1_AGGR1 to CMS_POPULARITY_SYSTEM_W; | ||
grant select, insert, update, delete on MV_DS_STAT1_AGGR1_SUMM to CMS_POPULARITY_SYSTEM_W; | ||
grant select, insert, update, delete on MV_DS_STAT1_AGGR2 to CMS_POPULARITY_SYSTEM_W; | ||
grant select, insert, update, delete on MV_DS_STAT1_AGGR2_SUMM to CMS_POPULARITY_SYSTEM_W; | ||
grant select, insert, update, delete on MV_DS_STAT1_AGGR4 to CMS_POPULARITY_SYSTEM_W; | ||
grant select, insert, update, delete on MV_DS_STAT1_AGGR4_SUMM to CMS_POPULARITY_SYSTEM_W; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
124 changes: 124 additions & 0 deletions
124
DataPopularity/popdb.crab/collector/config/db/MigratePopDB03.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,124 @@ | ||
-- SQL USED FOR POPDB SCHEMA MIGRATION ON 2015-05-24 | ||
-- NOT TO BE USED FOR A FRESH SCHEMA DEPLOYMENT | ||
-- TO DEPLOY SCHEMA FROM SCRATCH, RUN CreateMVTable | ||
-- and CreateMVDSStat1 | ||
|
||
DROP MATERIALIZED VIEW MV_DS_stat0; | ||
|
||
CREATE MATERIALIZED VIEW MV_DS_stat0 | ||
COMPRESS | ||
PCTFREE 0 | ||
BUILD IMMEDIATE | ||
REFRESH FAST | ||
ENABLE QUERY REWRITE | ||
AS | ||
select trunc(finishedtimestamp) as TDay , siteName, userid, inputcollection as collName, isRemote, | ||
submissiontool, | ||
count(*) as numAccesses, sum(CPUTIME) as totCPU | ||
from raw_file | ||
where fileexitflag=1 | ||
GROUP BY trunc(finishedtimestamp), siteName, userid, inputcollection, isRemote, submissiontool | ||
; | ||
|
||
CREATE MATERIALIZED VIEW MV_DS_stat1_aggr1 | ||
COMPRESS | ||
PCTFREE 0 | ||
BUILD IMMEDIATE | ||
ENABLE QUERY REWRITE | ||
AS | ||
select TDay , siteName, collName, | ||
sum(numAccesses) as numAccesses, sum(totCPU) as totCPU, count(distinct userid) as numUsers | ||
from MV_DS_stat0 | ||
where submissiontool!='wmagent' | ||
GROUP BY TDay, siteName, collName | ||
; | ||
|
||
CREATE MATERIALIZED VIEW MV_DS_stat1_aggr1_summ | ||
COMPRESS | ||
PCTFREE 0 | ||
BUILD IMMEDIATE | ||
ENABLE QUERY REWRITE | ||
AS | ||
select TDay , collName, | ||
sum(numAccesses) as numAccesses, sum(totCPU) as totCPU, count(distinct userid) as numUsers | ||
from MV_DS_stat0 | ||
where submissiontool!='wmagent' | ||
GROUP BY TDay, collName | ||
; | ||
|
||
CREATE MATERIALIZED VIEW MV_DS_stat1_aggr2 | ||
COMPRESS | ||
PCTFREE 0 | ||
BUILD IMMEDIATE | ||
ENABLE QUERY REWRITE | ||
AS | ||
select TDay , siteName, substr(collName,INSTR(collName, '/',-1)+1) as collName, | ||
sum(numAccesses) as numAccesses, sum(totCPU) as totCPU, count (distinct userid) as numUsers | ||
from MV_DS_stat0 | ||
where submissiontool!='wmagent' | ||
GROUP BY TDay, siteName, substr(collName,INSTR(collName, '/',-1)+1) | ||
; | ||
|
||
CREATE MATERIALIZED VIEW MV_DS_stat1_aggr2_summ | ||
COMPRESS | ||
PCTFREE 0 | ||
BUILD IMMEDIATE | ||
ENABLE QUERY REWRITE | ||
AS | ||
select TDay , substr(collName,INSTR(collName, '/',-1)+1) as collName, | ||
sum(numAccesses) as numAccesses, sum(totCPU) as totCPU, count (distinct userid) as numUsers | ||
from MV_DS_stat0 | ||
where submissiontool!='wmagent' | ||
GROUP BY TDay, substr(collName,INSTR(collName, '/',-1)+1) | ||
; | ||
|
||
CREATE MATERIALIZED VIEW MV_DS_stat1_aggr4 | ||
COMPRESS | ||
PCTFREE 0 | ||
BUILD IMMEDIATE | ||
ENABLE QUERY REWRITE | ||
AS | ||
select TDay , siteName, | ||
substr(collname,INSTR(collname, '/',-1,2)+1,INSTR(collname, '/',-1,1)-INSTR(collname, '/',-1,2)-1) as collName, | ||
sum(numAccesses) as numAccesses, sum(totCPU) as totCPU, count (distinct userid) as numUsers | ||
from MV_DS_stat0 | ||
where | ||
substr(collname,INSTR(collname, '/',-1,1)+1) not like 'USER' | ||
and | ||
collname not like 'unknown' | ||
and submissiontool!='wmagent' | ||
GROUP BY TDay, siteName, substr(collname,INSTR(collname, '/',-1,2)+1,INSTR(collname, '/',-1,1)-INSTR(collname, '/',-1,2)-1) | ||
; | ||
|
||
CREATE MATERIALIZED VIEW MV_DS_stat1_aggr4_summ | ||
COMPRESS | ||
PCTFREE 0 | ||
BUILD IMMEDIATE | ||
ENABLE QUERY REWRITE | ||
AS | ||
select TDay , | ||
substr(collname,INSTR(collname, '/',-1,2)+1,INSTR(collname, '/',-1,1)-INSTR(collname, '/',-1,2)-1) as collName, | ||
sum(numAccesses) as numAccesses, sum(totCPU) as totCPU, count (distinct userid) as numUsers | ||
from MV_DS_stat0 | ||
where | ||
substr(collname,INSTR(collname, '/',-1,1)+1) not like 'USER' | ||
and | ||
collname not like 'unknown' | ||
and submissiontool!='wmagent' | ||
GROUP BY TDay, substr(collname,INSTR(collname, '/',-1,2)+1,INSTR(collname, '/',-1,1)-INSTR(collname, '/',-1,2)-1) | ||
; | ||
|
||
grant select on MV_DS_STAT1_AGGR1 to CMS_POPULARITY_SYSTEM_R; | ||
grant select on MV_DS_STAT1_AGGR1_SUMM to CMS_POPULARITY_SYSTEM_R; | ||
grant select on MV_DS_STAT1_AGGR2 to CMS_POPULARITY_SYSTEM_R; | ||
grant select on MV_DS_STAT1_AGGR2_SUMM to CMS_POPULARITY_SYSTEM_R; | ||
grant select on MV_DS_STAT1_AGGR4 to CMS_POPULARITY_SYSTEM_R; | ||
grant select on MV_DS_STAT1_AGGR4_SUMM to CMS_POPULARITY_SYSTEM_R; | ||
|
||
grant select, insert, update, delete on MV_DS_STAT0 to CMS_POPULARITY_SYSTEM_W; | ||
grant select, insert, update, delete on MV_DS_STAT1_AGGR1 to CMS_POPULARITY_SYSTEM_W; | ||
grant select, insert, update, delete on MV_DS_STAT1_AGGR1_SUMM to CMS_POPULARITY_SYSTEM_W; | ||
grant select, insert, update, delete on MV_DS_STAT1_AGGR2 to CMS_POPULARITY_SYSTEM_W; | ||
grant select, insert, update, delete on MV_DS_STAT1_AGGR2_SUMM to CMS_POPULARITY_SYSTEM_W; | ||
grant select, insert, update, delete on MV_DS_STAT1_AGGR4 to CMS_POPULARITY_SYSTEM_W; | ||
grant select, insert, update, delete on MV_DS_STAT1_AGGR4_SUMM to CMS_POPULARITY_SYSTEM_W; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Oops, something went wrong.