From 865725c0be5ec61915e6c3030939bd5642c70260 Mon Sep 17 00:00:00 2001 From: Bernhard Urban Date: Tue, 2 Aug 2016 22:22:11 +0200 Subject: [PATCH] postgres: update definitions. --- postgresql/README.md | 2 +- postgresql/drop.psql.in | 25 --- postgresql/dropowned.psql.in | 1 - postgresql/init.psql.in | 197 ++++++++++++------ postgresql/newtables.psql.in | 9 - postgresql/restructure.psql.in | 108 ---------- postgresql/views.psql.in | 365 +++++++++++++++++++++++++-------- 7 files changed, 414 insertions(+), 293 deletions(-) delete mode 100644 postgresql/drop.psql.in delete mode 100644 postgresql/dropowned.psql.in delete mode 100644 postgresql/newtables.psql.in delete mode 100644 postgresql/restructure.psql.in diff --git a/postgresql/README.md b/postgresql/README.md index cddc290e..48566ac9 100644 --- a/postgresql/README.md +++ b/postgresql/README.md @@ -1,6 +1,6 @@ # Postgres hosting -Our Postgres is currently hosted on Amazon's RDS. The credentials are +Our Postgres is currently hosted on an Azure instance. The credentials are in [Accredit](../accredit/README.md): - `adminPostgres`: The administrator credentials. Should only be diff --git a/postgresql/drop.psql.in b/postgresql/drop.psql.in deleted file mode 100644 index 90761b78..00000000 --- a/postgresql/drop.psql.in +++ /dev/null @@ -1,25 +0,0 @@ -drop view "1".benchmark cascade; -drop view "1".config cascade; -drop view "1".machine cascade; -drop view "1".parseobjectid cascade; -drop view "1".runsetcount cascade; -drop view "1".runset cascade; -drop view "1".results cascade; -drop view "1".summary cascade; -drop view "1".pullrequest cascade; -drop schema "1" cascade; - -drop table RunMetric cascade; -drop table ParseObjectID cascade; -alter table RunSet drop constraint runset_pullrequest_fkey; -drop table PullRequest cascade; -drop table RegressionWarnings cascade; -drop table Run cascade; -drop table RunSet cascade; -drop table Benchmark cascade; -drop table Machine cascade; -drop table Commit cascade; -drop table Config cascade; - -drop role $POSTGREST_USER; -drop role $BENCHMARKER_USER; diff --git a/postgresql/dropowned.psql.in b/postgresql/dropowned.psql.in deleted file mode 100644 index d5969262..00000000 --- a/postgresql/dropowned.psql.in +++ /dev/null @@ -1 +0,0 @@ -drop owned by $USER cascade; diff --git a/postgresql/init.psql.in b/postgresql/init.psql.in index 3bd60bbe..24e42347 100644 --- a/postgresql/init.psql.in +++ b/postgresql/init.psql.in @@ -3,84 +3,157 @@ create database $DATABASE; \c $DATABASE -create table Benchmark ( - objectId varchar(10), - name varchar(128) primary key, - disabled boolean +CREATE TABLE benchmark ( + id serial, + name character varying(128) NOT NULL, + disabled boolean, + CONSTRAINT benchmark_pkey PRIMARY KEY (id) ); -create table Machine ( - objectId varchar(10), - name varchar(128) primary key, - architecture varchar(128), - isDedicated boolean, - check (name <> '') + +CREATE TABLE machine ( + id serial, + name character varying(128) NOT NULL, + architecture character varying(128), + isdedicated boolean, + CONSTRAINT machine_pkey PRIMARY KEY (id), + CONSTRAINT machine_name_check CHECK (((name)::text <> ''::text)) +); + + +CREATE TABLE commit ( + id serial, + hash character varying(40) NOT NULL, + commitdate timestamp with time zone, + branch character varying(128), + mergebasehash character varying(40), + product character varying(128), + CONSTRAINT commit_pkey PRIMARY KEY (id), + CONSTRAINT commit_hash_check CHECK (((hash)::text <> ''::text)) ); -create table Commit ( - objectId varchar(10), - hash varchar(40) primary key, - product varchar(128), - commitDate timestamp with time zone, - branch varchar(128), - mergeBaseHash varchar(40), - check (hash <> '') +CREATE TABLE config ( + id serial, + name character varying(128) NOT NULL, + monoexecutable character varying(128), + monoenvironmentvariables jsonb, + monooptions text[], + CONSTRAINT config_pkey PRIMARY KEY (id), + CONSTRAINT config_name_check CHECK (((name)::text <> ''::text)) ); -create table Config ( - objectId varchar(10), - name varchar(128) primary key, - monoExecutable varchar(128), - monoEnvironmentVariables jsonb, - monoOptions text[], - check (name <> '') +CREATE TABLE metric ( + id serial, + name character varying(128) NOT NULL, + CONSTRAINT metric_pkey PRIMARY KEY (id) ); -create table RunSet ( - objectId varchar(10), - id serial primary key, - startedAt timestamp with time zone, - finishedAt timestamp with time zone, - buildURL varchar(256), - elapsedTimeAverages jsonb, - elapsedTimeVariances jsonb, - failed boolean, - logURLs jsonb, - commit varchar(40) references Commit(hash), - secondaryCommits varchar(40)[], - machine varchar(128) references Machine(name), - config varchar(128) references Config(name), - pullRequest integer, - timedOutBenchmarks varchar(128)[], -- element references Benchmark(name), - crashedBenchmarks varchar(128)[] -- element references Benchmark(name) - -- pullRequest integer references PullRequest(id) +CREATE TABLE runset ( + id serial, + startedat timestamp with time zone, + finishedat timestamp with time zone, + buildurl character varying(256), + logurls jsonb, + commit integer, + machine integer, + config integer, + pullrequest integer, + timedoutbenchmarks character varying(128)[], + crashedbenchmarks character varying(128)[], + secondarycommits character varying(40)[], + CONSTRAINT runset_pkey PRIMARY KEY (id), + CONSTRAINT runset_commit_fkey FOREIGN KEY (commit) + REFERENCES commit (id) MATCH SIMPLE + ON UPDATE NO ACTION ON DELETE NO ACTION, + CONSTRAINT runset_config_fkey FOREIGN KEY (config) + REFERENCES config (id) MATCH SIMPLE + ON UPDATE NO ACTION ON DELETE NO ACTION, + CONSTRAINT runset_machine_fkey FOREIGN KEY (machine) + REFERENCES machine (id) MATCH SIMPLE + ON UPDATE NO ACTION ON DELETE NO ACTION ); -create table Run ( - objectId varchar(10), - id serial primary key, - elapsedMilliseconds integer, - benchmark varchar(128) references Benchmark(name), - runSet integer references RunSet(id) +CREATE INDEX runset_commit_index ON runset USING btree (commit); + +CREATE TABLE run ( + id serial, + benchmark integer, + runset integer, + CONSTRAINT run_pkey PRIMARY KEY (id), + CONSTRAINT run_benchmark_fkey FOREIGN KEY (benchmark) + REFERENCES benchmark (id) MATCH SIMPLE + ON UPDATE NO ACTION ON DELETE NO ACTION, + CONSTRAINT run_runset_fkey FOREIGN KEY (runset) + REFERENCES runset (id) MATCH SIMPLE + ON UPDATE NO ACTION ON DELETE NO ACTION ); -create table RegressionWarnings ( - objectId varchar(10), - id serial primary key, - runSet integer references RunSet(id), - fasterBenchmarks varchar(128)[], -- element references Benchmark(name), - slowerBenchmarks varchar(128)[] -- element references Benchmark(name) +CREATE INDEX run_runset_index ON run USING btree (runset); + +CREATE TABLE runmetric ( + id serial, + run integer, + metric integer, + result double precision, + resultarray double precision[], + CONSTRAINT runmetric_pkey PRIMARY KEY (id), + CONSTRAINT runmetric_metric_fkey FOREIGN KEY (metric) + REFERENCES metric (id) MATCH SIMPLE + ON UPDATE NO ACTION ON DELETE NO ACTION, + CONSTRAINT runmetric_run_fkey FOREIGN KEY (run) + REFERENCES run (id) MATCH SIMPLE + ON UPDATE NO ACTION ON DELETE NO ACTION ); -create table PullRequest ( - objectId varchar(10), - id serial primary key, - URL varchar(256), - baselineRunSet integer references RunSet(id) +CREATE TABLE regressionswarned ( + id serial, + runset integer, + benchmark integer, + faster boolean, + CONSTRAINT regressionswarned_pkey PRIMARY KEY (id), + CONSTRAINT regressionswarned_benchmark_fkey FOREIGN KEY (benchmark) + REFERENCES benchmark (id) MATCH SIMPLE + ON UPDATE NO ACTION ON DELETE NO ACTION, + CONSTRAINT regressionswarned_runset_fkey FOREIGN KEY (runset) + REFERENCES runset (id) MATCH SIMPLE + ON UPDATE NO ACTION ON DELETE NO ACTION ); -alter table RunSet add foreign key (pullRequest) references PullRequest(id); +CREATE TABLE pullrequest ( + id serial, + url character varying(256), + baselinerunset integer, + CONSTRAINT pullrequest_pkey PRIMARY KEY (id), + CONSTRAINT pullrequest_baselinerunset_fkey FOREIGN KEY (baselinerunset) + REFERENCES runset (id) MATCH SIMPLE + ON UPDATE NO ACTION ON DELETE NO ACTION +); + +CREATE TABLE featuredtimelines ( + id serial, + name character varying(128), + machine integer, + config integer, + metric integer, + CONSTRAINT featuredtimelines_pkey PRIMARY KEY (id), + CONSTRAINT featuredtimelines_config_fkey FOREIGN KEY (config) + REFERENCES config (id) MATCH SIMPLE + ON UPDATE NO ACTION ON DELETE NO ACTION, + CONSTRAINT featuredtimelines_machine_fkey FOREIGN KEY (machine) + REFERENCES machine (id) MATCH SIMPLE + ON UPDATE NO ACTION ON DELETE NO ACTION, + CONSTRAINT featuredtimelines_metric_fkey FOREIGN KEY (metric) + REFERENCES metric (id) MATCH SIMPLE + ON UPDATE NO ACTION ON DELETE NO ACTION +); + +CREATE TABLE parseobjectid ( + parseid character(10) NOT NULL, + tablename character varying(32), + integerkey integer, + varcharkey character varying(128) +); create user $BENCHMARKER_USER login encrypted password '$BENCHMARKER_PASSWORD'; -grant select, insert, update, delete on table Benchmark, Commit, Config, Machine, PullRequest, RegressionWarnings, Run, RunSet to $BENCHMARKER_USER; +grant select, insert, update, delete on table Benchmark, Commit, Config, Machine, PullRequest, RegressionWarnings, Run, RunSet, metric to $BENCHMARKER_USER; grant usage, select, update on sequence runset_id_seq, pullrequest_id_seq, run_id_seq, regressionwarnings_id_seq to $BENCHMARKER_USER; diff --git a/postgresql/newtables.psql.in b/postgresql/newtables.psql.in deleted file mode 100644 index 539af47c..00000000 --- a/postgresql/newtables.psql.in +++ /dev/null @@ -1,9 +0,0 @@ --- FeaturedTimelines - -create table FeaturedTimelines ( - id serial primary key, - name varchar(128), - machine varchar(128) references Machine(name), - config varchar(128) references Config(name), - metric varchar(32) -); diff --git a/postgresql/restructure.psql.in b/postgresql/restructure.psql.in deleted file mode 100644 index aaa6d126..00000000 --- a/postgresql/restructure.psql.in +++ /dev/null @@ -1,108 +0,0 @@ --- -*- sql -*- - --- ParseObjectID table - -create table ParseObjectID ( - parseID char(10) primary key, - tableName varchar(32), - integerKey integer, - varcharKey varchar(128) -); - -insert into ParseObjectId (parseID, tableName, varcharKey) -select b.objectId, 'Benchmark', b.name -from Benchmark b; - -alter table Benchmark drop column objectId; - -insert into ParseObjectId (parseID, tableName, varcharKey) -select m.objectId, 'Machine', m.name -from Machine m; - -alter table Machine drop column objectId; - -insert into ParseObjectId (parseID, tableName, varcharKey) -select c.objectId, 'Commit', c.hash -from Commit c; - -alter table Commit drop column objectId; - -insert into ParseObjectId (parseID, tableName, varcharKey) -select c.objectId, 'Config', c.name -from Config c; - -alter table Config drop column objectId; - -insert into ParseObjectId (parseID, tableName, integerKey) -select rs.objectId, 'RunSet', rs.id -from RunSet rs; - -alter table RunSet drop column objectId; - -insert into ParseObjectId (parseID, tableName, integerKey) -select r.objectId, 'Run', r.id -from Run r; - -alter table Run drop column objectId; - -insert into ParseObjectId (parseID, tableName, integerKey) -select rw.objectId, 'RegressionWarnings', rw.id -from RegressionWarnings rw; - -alter table RegressionWarnings drop column objectId; - -insert into ParseObjectId (parseID, tableName, integerKey) -select pr.objectId, 'PullRequest', pr.id -from PullRequest pr; - -alter table PullRequest drop column objectId; - --- RunMetric - -create table RunMetric ( - id serial primary key, - run integer references Run(id), - metric text, - result double precision, - resultArray double precision[] -); - -insert into RunMetric (run, result, metric) -select r.id, r.elapsedMilliseconds, 'time' -from run r; - -alter table Run drop column elapsedMilliseconds; - -alter table RunSet drop column elapsedTimeAverages; -alter table RunSet drop column elapsedTimeVariances; -alter table RunSet drop column failed; - -grant select, insert, update, delete on table RunMetric to $BENCHMARKER_USER; -grant usage, select, update on sequence runmetric_id_seq to $BENCHMARKER_USER; - --- RegressionsWarned - -create table RegressionsWarned ( - id serial primary key, - runSet integer references RunSet(id), - benchmark varchar(128) references Benchmark(name), - faster boolean -); - -insert into regressionsWarned (runSet, benchmark, faster) -select runset, unnest(fasterbenchmarks), true -from regressionwarnings; - -insert into regressionsWarned (runSet, benchmark, faster) -select runset, unnest(slowerbenchmarks), false -from regressionwarnings; - -drop table RegressionWarnings; - -grant select, insert, update, delete on table RegressionsWarned to $BENCHMARKER_USER; -grant usage, select, update on sequence regressionswarned_id_seq to $BENCHMARKER_USER; - --- indexes - -create index runmetric_run_index on runmetric (run); -create index run_runset_index on run (runset); diff --git a/postgresql/views.psql.in b/postgresql/views.psql.in index d34dcf62..6fbfa9d2 100644 --- a/postgresql/views.psql.in +++ b/postgresql/views.psql.in @@ -2,93 +2,284 @@ create schema "1"; -create view "1".benchmark as -select * from benchmark; - -create view "1".config as -select * from config; - -create view "1".machine as -select * from machine; - -create view "1".parseobjectid as -select * from parseobjectid; - -create view "1".commit as -select * from commit; - -create view "1".summary as -select results.runset as rs_id, rs.machine as rs_machine, rs.config as rs_config, rs.pullrequest as rs_pullrequest, rs.startedAt as rs_startedAt, rs.timedOutBenchmarks as rs_timedoutBenchmarks, rs.crashedBenchmarks as rs_crashedBenchmarks, - c.hash as c_hash, c.commitDate as c_commitDate, c.product as c_product, - m.name as m_name, m.architecture as m_architecture, m.isdedicated as m_isdedicated, - cfg.name as cfg_name, cfg.monoexecutable as cfg_monoexecutable, cfg.monoenvironmentvariables as cfg_monoenvironmentvariables, cfg.monooptions as cfg_monooptions, - results.metric, results.averages, results.variances from ( -select x.runset, x.metric, json_object_agg(x.benchmark, x.avg) as averages, json_object_agg(x.benchmark, x.var_pop) as variances -from ( -select r.runset, rm.metric, r.benchmark, avg(rm.result), var_pop(rm.result) -from run r, runmetric rm, benchmark b -where r.id = rm.run and r.benchmark = b.name and b.disabled is not true and rm.result is not null -group by r.runset, r.benchmark, rm.metric -) as x -group by runset, metric -) as results, -runset rs, commit c, machine m, config cfg -where results.runset = rs.id and rs.commit = c.hash and rs.machine = m.name and rs.config = cfg.name; - -create or replace view "1".runset as -select c.hash as c_hash, c.commitdate as c_commitdate, - rs.id as rs_id, rs.startedat as rs_startedat, rs.finishedat as rs_finishedat, rs.buildurl as rs_buildurl, rs.logurls as rs_logurls, rs.commit as rs_commit, rs.machine as rs_machine, rs.config as rs_config, rs.timedoutbenchmarks as rs_timedoutbenchmarks, rs.crashedbenchmarks as rs_crashedbenchmarks, - m.name as m_name, m.architecture as m_architecture, m.isdedicated as m_isdedicated, - cfg.name as cfg_name, cfg.monoexecutable as cfg_monoexecutable, cfg.monoenvironmentvariables as cfg_monoenvironmentvariables, cfg.monooptions as cfg_monooptions, - rs.secondarycommits as rs_secondarycommits, - c.product as c_product, rs.pullrequest as rs_pullrequest -from runset rs, commit c, machine m, config cfg -where rs.commit = c.hash and rs.machine = m.name and rs.config = cfg.name; - -create view "1".runsetcount as -select array_agg(rs.id) as ids, - m.name as m_name, m.architecture as m_architecture, m.isdedicated as m_isdedicated, - cfg.name as cfg_name, cfg.monoexecutable as cfg_monoexecutable, cfg.monoenvironmentvariables as cfg_monoenvironmentvariables, cfg.monooptions as cfg_monooptions, - rs.metric -from (select distinct irs.id, rm.metric, irs.machine, irs.config - from runset irs, run r, runmetric rm - where irs.pullrequest is null and rm.run = r.id and r.runset = irs.id) rs, - machine m, config cfg -where rs.machine = m.name and rs.config = cfg.name -group by rs.metric, m.name, m.architecture, m.isdedicated, cfg.name, cfg.monoexecutable, cfg.monoenvironmentvariables, cfg.monooptions; - -create view "1".results as -select r.runset, r.benchmark, b.disabled, rm.metric, array_agg(rm.result) as results -from run r, runmetric rm, benchmark b -where rm.run = r.id and r.benchmark = b.name and rm.result is not null -group by r.runset, r.benchmark, rm.metric, b.disabled; - -create view "1".resultarrays as -select rs.id as rs_id, rs.machine as rs_machine, rs.config as rs_config, rs.pullrequest as rs_pullrequest, rs.startedAt as rs_startedAt, rs.timedOutBenchmarks as rs_timedoutBenchmarks, rs.crashedBenchmarks as rs_crashedBenchmarks, - r.benchmark, b.disabled, rm.metric, rm.resultarray, - c.hash as c_hash, c.commitDate as c_commitDate, c.product as c_product, - r.id as r_id -from run r, runmetric rm, benchmark b, runset rs, commit c -where rs.commit = c.hash and r.runset = rs.id and rm.run = r.id and r.benchmark = b.name and rm.resultarray is not null; - -create view "1".resultarraybenchmarks as -select distinct r.benchmark, b.disabled, rm.metric, rs.machine, rs.config -from run r, runmetric rm, benchmark b, runset rs -where r.runset = rs.id and rm.run = r.id and r.benchmark = b.name and rm.resultarray is not null; - -create view "1".pullrequest as -select pr.id as pr_id, pr.url as pr_url, - blrs.id as blrs_id, blrs.startedAt as blrs_startedAt, blrs.finishedAt as blrs_finishedAt, blrs.buildURL as blrs_buildURL, blrs.logURLs as blrs_logURLs, blrs.commit as blrs_commit, blrs.machine as blrs_machine, blrs.config as blrs_config, blrs.timedOutBenchmarks as blrs_timedOutBenchmarks, blrs.crashedBenchmarks as blrs_crashedBenchmarks, - prrs.id as prrs_id, prrs.startedAt as prrs_startedAt, prrs.finishedAt as prrs_finishedAt, prrs.buildURL as prrs_buildURL, prrs.logURLs as prrs_logURLs, prrs.commit as prrs_commit, prrs.machine as prrs_machine, prrs.config as prrs_config, prrs.timedOutBenchmarks as prrs_timedOutBenchmarks, prrs.crashedBenchmarks as prrs_crashedBenchmarks, - blc.hash as blc_hash, blc.commitDate as blc_commitDate, - prc.hash as prc_hash, prc.commitDate as prc_commitDate, - m.name as m_name, m.architecture as m_architecture, m.isdedicated as m_isdedicated, - cfg.name as cfg_name, cfg.monoexecutable as cfg_monoexecutable, cfg.monoenvironmentvariables as cfg_monoenvironmentvariables, cfg.monooptions as cfg_monooptions -from pullrequest as pr, runset as blrs, runset as prrs, commit as blc, commit as prc, machine as m, config cfg -where pr.baselinerunset = blrs.id and prrs.pullrequest = pr.id and blc.hash = blrs.commit and prc.hash = prrs.commit and blrs.machine = m.name and blrs.config = cfg.name; - -create view "1".featuredtimelines as -select * from featuredtimelines; +CREATE OR REPLACE VIEW "1".benchmark AS + SELECT b.name, + b.disabled + FROM benchmark b; + +CREATE OR REPLACE VIEW "1".commit AS + SELECT c.hash, + c.commitdate, + c.branch, + c.mergebasehash, + c.product + FROM commit c; + +CREATE OR REPLACE VIEW "1".config AS + SELECT cfg.name, + cfg.monoexecutable, + cfg.monoenvironmentvariables, + cfg.monooptions + FROM config cfg; + +CREATE OR REPLACE VIEW "1".machine AS + SELECT m.name, + m.architecture, + m.isdedicated + FROM machine m; + +CREATE OR REPLACE VIEW "1".featuredtimelines AS + SELECT ft.id, + ft.name, + m.name AS machine, + cfg.name AS config, + metric.name AS metric + FROM featuredtimelines ft, + machine m, + config cfg, + metric + WHERE ft.machine = m.id AND ft.config = cfg.id AND metric.id = ft.metric; + +CREATE OR REPLACE VIEW "1".parseobjectid AS + SELECT parseobjectid.parseid, + parseobjectid.tablename, + parseobjectid.integerkey, + parseobjectid.varcharkey + FROM parseobjectid; + +CREATE OR REPLACE VIEW "1".summary AS + SELECT results.runset AS rs_id, + m.name AS rs_machine, + cfg.name AS rs_config, + rs.pullrequest AS rs_pullrequest, + rs.startedat AS rs_startedat, + rs.timedoutbenchmarks AS rs_timedoutbenchmarks, + rs.crashedbenchmarks AS rs_crashedbenchmarks, + c.hash AS c_hash, + c.commitdate AS c_commitdate, + m.name AS m_name, + m.architecture AS m_architecture, + m.isdedicated AS m_isdedicated, + cfg.name AS cfg_name, + cfg.monoexecutable AS cfg_monoexecutable, + cfg.monoenvironmentvariables AS cfg_monoenvironmentvariables, + cfg.monooptions AS cfg_monooptions, + metric.name AS metric, + results.averages, + results.variances, + c.product AS c_product + FROM ( SELECT x.runset, + x.metric, + json_object_agg(b.name, x.avg) AS averages, + json_object_agg(b.name, x.var_pop) AS variances + FROM ( SELECT r.runset, + rm.metric, + r.benchmark, + avg(rm.result) AS avg, + var_pop(rm.result) AS var_pop + FROM run r, + runmetric rm, + benchmark b_1 + WHERE r.id = rm.run AND r.benchmark = b_1.id AND b_1.disabled IS NOT TRUE AND rm.result IS NOT NULL + GROUP BY r.runset, r.benchmark, rm.metric) x, + benchmark b + WHERE x.benchmark = b.id + GROUP BY x.runset, x.metric) results, + runset rs, + commit c, + machine m, + config cfg, + metric + WHERE metric.id = results.metric AND results.runset = rs.id AND rs.commit = c.id AND rs.machine = m.id AND rs.config = cfg.id; + + +CREATE OR REPLACE VIEW "1".runset AS + SELECT c.hash AS c_hash, + c.commitdate AS c_commitdate, + rs.id AS rs_id, + rs.startedat AS rs_startedat, + rs.finishedat AS rs_finishedat, + rs.buildurl AS rs_buildurl, + rs.logurls AS rs_logurls, + c.hash AS rs_commit, + m.name AS rs_machine, + cfg.name AS rs_config, + rs.timedoutbenchmarks AS rs_timedoutbenchmarks, + rs.crashedbenchmarks AS rs_crashedbenchmarks, + m.name AS m_name, + m.architecture AS m_architecture, + m.isdedicated AS m_isdedicated, + cfg.name AS cfg_name, + cfg.monoexecutable AS cfg_monoexecutable, + cfg.monoenvironmentvariables AS cfg_monoenvironmentvariables, + cfg.monooptions AS cfg_monooptions, + rs.secondarycommits AS rs_secondarycommits, + c.product AS c_product, + rs.pullrequest AS rs_pullrequest + FROM runset rs, + commit c, + machine m, + config cfg + WHERE rs.commit = c.id AND rs.machine = m.id AND rs.config = cfg.id; + +CREATE OR REPLACE VIEW "1".runsetcount AS + SELECT array_agg(rs.id) AS ids, + m.name AS m_name, + m.architecture AS m_architecture, + m.isdedicated AS m_isdedicated, + cfg.name AS cfg_name, + cfg.monoexecutable AS cfg_monoexecutable, + cfg.monoenvironmentvariables AS cfg_monoenvironmentvariables, + cfg.monooptions AS cfg_monooptions, + metric.name AS metric + FROM ( SELECT DISTINCT irs.id, + rm.metric, + irs.machine, + irs.config + FROM ( SELECT DISTINCT iirs.id, + iirs.machine, + iirs.config + FROM runset iirs + WHERE iirs.pullrequest IS NULL) irs, + run r, + runmetric rm + WHERE rm.run = r.id AND r.runset = irs.id) rs, + machine m, + config cfg, + metric + WHERE rs.machine = m.id AND rs.config = cfg.id AND rs.metric = metric.id + GROUP BY metric.name, m.id, m.architecture, m.isdedicated, cfg.id, cfg.monoexecutable, cfg.monoenvironmentvariables, cfg.monooptions; + + +CREATE OR REPLACE VIEW "1".results AS + SELECT res.runset, + b.name AS benchmark, + res.disabled, + metric.name AS metric, + res.results + FROM ( SELECT r.runset, + b_1.id, + b_1.disabled, + rm.metric, + array_agg(rm.result) AS results + FROM run r, + runmetric rm, + benchmark b_1 + WHERE rm.run = r.id AND r.benchmark = b_1.id AND rm.result IS NOT NULL + GROUP BY r.runset, b_1.id, rm.metric, b_1.disabled) res, + benchmark b, + metric + WHERE res.id = b.id AND metric.id = res.metric; + +CREATE OR REPLACE VIEW "1".resultarrays AS + SELECT res.rs_id, + m.name AS rs_machine, + cfg.name AS rs_config, + res.rs_pullrequest, + res.rs_startedat, + res.rs_timedoutbenchmarks, + res.rs_crashedbenchmarks, + res.benchmark, + res.disabled, + metric.name AS metric, + res.resultarray, + res.c_hash, + res.c_commitdate, + res.c_product, + res.r_id + FROM ( SELECT rs.id AS rs_id, + rs.machine AS trs_machine, + rs.config AS rs_config, + rs.pullrequest AS rs_pullrequest, + rs.startedat AS rs_startedat, + rs.timedoutbenchmarks AS rs_timedoutbenchmarks, + rs.crashedbenchmarks AS rs_crashedbenchmarks, + b.name AS benchmark, + b.disabled, + rm.metric, + rm.resultarray, + c.hash AS c_hash, + c.commitdate AS c_commitdate, + c.product AS c_product, + r.id AS r_id + FROM run r, + runmetric rm, + benchmark b, + runset rs, + commit c + WHERE rs.commit = c.id AND r.runset = rs.id AND rm.run = r.id AND r.benchmark = b.id AND rm.resultarray IS NOT NULL) res, + metric, + config cfg, + machine m + WHERE res.metric = metric.id AND res.rs_config = cfg.id AND res.trs_machine = m.id; + +CREATE OR REPLACE VIEW "1".resultarraybenchmarks AS + SELECT benchmark.name AS benchmark, + benchmark.disabled, + metric.name AS metric, + machine.name AS machine, + config.name AS config + FROM benchmark benchmark, + metric, + machine machine, + config config, + ( SELECT DISTINCT r.benchmark, + b.disabled, + rm.metric, + rs.machine, + rs.config + FROM run r, + runmetric rm, + benchmark b, + runset rs + WHERE r.runset = rs.id AND rm.run = r.id AND r.benchmark = b.id AND rm.resultarray IS NOT NULL) res + WHERE res.benchmark = benchmark.id AND metric.id = res.metric AND res.machine = machine.id AND res.config = config.id; + +CREATE OR REPLACE VIEW "1".pullrequest AS + SELECT pr.id AS pr_id, + pr.url AS pr_url, + blrs.id AS blrs_id, + blrs.startedat AS blrs_startedat, + blrs.finishedat AS blrs_finishedat, + blrs.buildurl AS blrs_buildurl, + blrs.logurls AS blrs_logurls, + blc.hash AS blrs_commit, + blm.name AS blrs_machine, + blcfg.name AS blrs_config, + blrs.timedoutbenchmarks AS blrs_timedoutbenchmarks, + blrs.crashedbenchmarks AS blrs_crashedbenchmarks, + prrs.id AS prrs_id, + prrs.startedat AS prrs_startedat, + prrs.finishedat AS prrs_finishedat, + prrs.buildurl AS prrs_buildurl, + prrs.logurls AS prrs_logurls, + prc.hash AS prrs_commit, + prm.name AS prrs_machine, + prcfg.name AS prrs_config, + prrs.timedoutbenchmarks AS prrs_timedoutbenchmarks, + prrs.crashedbenchmarks AS prrs_crashedbenchmarks, + blc.hash AS blc_hash, + blc.commitdate AS blc_commitdate, + prc.hash AS prc_hash, + prc.commitdate AS prc_commitdate, + blm.name AS m_name, + blm.architecture AS m_architecture, + blm.isdedicated AS m_isdedicated, + blcfg.name AS cfg_name, + blcfg.monoexecutable AS cfg_monoexecutable, + blcfg.monoenvironmentvariables AS cfg_monoenvironmentvariables, + blcfg.monooptions AS cfg_monooptions + FROM pullrequest pr, + runset blrs, + runset prrs, + commit blc, + commit prc, + machine blm, + machine prm, + config blcfg, + config prcfg + WHERE pr.baselinerunset = blrs.id AND prrs.pullrequest = pr.id AND blc.id = blrs.commit AND prc.id = prrs.commit AND blrs.machine = blm.id AND prrs.machine = prm.id AND blrs.config = blcfg.id AND prrs.config = prcfg.id; + create user $POSTGREST_USER login encrypted password '$POSTGREST_PASSWORD'; grant usage on schema "1" to $POSTGREST_USER;