create table SchemaVersion (
version integer not null
);
create table Users (
userName text primary key not null,
fullName text,
emailAddress text not null,
password text not null, emailOnError integer not null default 0,
type text not null default 'hydra', publicDashboard boolean not null default false
);
create table UserRoles (
userName text not null,
role text not null,
primary key (userName, role),
foreign key (userName) references Users(userName) on delete cascade on update cascade
);
create table Projects (
name text primary key not null, displayName text not null, description text,
enabled integer not null default 1,
hidden integer not null default 0,
owner text not null,
homepage text, declfile text, decltype text, declvalue text, foreign key (owner) references Users(userName) on update cascade
);
create table ProjectMembers (
project text not null,
userName text not null,
primary key (project, userName),
foreign key (project) references Projects(name) on delete cascade on update cascade,
foreign key (userName) references Users(userName) on delete cascade on update cascade
);
create table Jobsets (
name text not null,
id serial not null,
project text not null,
description text,
nixExprInput text, nixExprPath text, errorMsg text, errorTime integer, lastCheckedTime integer, triggerTime integer, enabled integer not null default 1, enableEmail integer not null default 1,
hidden integer not null default 0,
emailOverride text not null,
keepnr integer not null default 3,
checkInterval integer not null default 300, schedulingShares integer not null default 100,
fetchErrorMsg text,
forceEval boolean,
startTime integer, type integer not null default 0, flake text,
constraint jobsets_schedulingshares_nonzero_check check (schedulingShares > 0),
constraint jobsets_type_known_check check (type = 0 or type = 1),
constraint jobsets_legacy_paths_check check ((type = 0) = (nixExprInput is not null and nixExprPath is not null and flake is null)),
constraint jobsets_flake_paths_check check ((type = 1) = (nixExprInput is null and nixExprPath is null and flake is not null)),
primary key (project, name),
foreign key (project) references Projects(name) on delete cascade on update cascade,
constraint Jobsets_id_unique UNIQUE(id)
);
create function notifyJobsetSharesChanged() returns trigger as 'begin notify jobset_shares_changed; return null; end;' language plpgsql;
create trigger JobsetSharesChanged after update on Jobsets for each row
when (old.schedulingShares != new.schedulingShares) execute procedure notifyJobsetSharesChanged();
create function notifyJobsetsAdded() returns trigger as 'begin notify jobsets_added; return null; end;' language plpgsql;
create trigger JobsetsAdded after insert on Jobsets execute procedure notifyJobsetsAdded();
create function notifyJobsetsDeleted() returns trigger as 'begin notify jobsets_deleted; return null; end;' language plpgsql;
create trigger JobsetsDeleted after delete on Jobsets execute procedure notifyJobsetsDeleted();
create function notifyJobsetSchedulingChanged() returns trigger as 'begin notify jobset_scheduling_changed; return null; end;' language plpgsql;
create trigger JobsetSchedulingChanged after update on Jobsets for each row
when (((old.triggerTime is distinct from new.triggerTime) and (new.triggerTime is not null))
or (old.checkInterval != new.checkInterval)
or (old.enabled != new.enabled))
execute procedure notifyJobsetSchedulingChanged();
create table JobsetRenames (
project text not null,
from_ text not null,
to_ text not null,
primary key (project, from_),
foreign key (project) references Projects(name) on delete cascade on update cascade,
foreign key (project, to_) references Jobsets(project, name) on delete cascade on update cascade
);
create table JobsetInputs (
project text not null,
jobset text not null,
name text not null,
type text not null, emailResponsible integer not null default 0, primary key (project, jobset, name),
foreign key (project, jobset) references Jobsets(project, name) on delete cascade on update cascade
);
create table JobsetInputAlts (
project text not null,
jobset text not null,
input text not null,
altnr integer not null,
value text, revision text,
primary key (project, jobset, input, altnr),
foreign key (project, jobset, input) references JobsetInputs(project, jobset, name) on delete cascade on update cascade
);
create table Builds (
id serial primary key not null,
finished integer not null,
timestamp integer not null,
jobset_id integer not null,
job text not null,
nixName text, description text, drvPath text not null,
system text not null,
license text, homepage text, maintainers text, maxsilent integer default 3600, timeout integer default 36000,
isChannel integer not null default 0, isCurrent integer default 0,
priority integer not null default 0,
globalPriority integer not null default 0,
startTime integer, stopTime integer,
isCachedBuild integer,
buildStatus integer,
size bigint,
closureSize bigint,
releaseName text,
keep integer not null default 0,
notificationPendingSince integer,
check (finished = 0 or (stoptime is not null and stoptime != 0)),
check (finished = 0 or (starttime is not null and starttime != 0)),
foreign key (jobset_id) references Jobsets(id) on delete cascade
);
create function notifyBuildsDeleted() returns trigger as 'begin notify builds_deleted; return null; end;' language plpgsql;
create trigger BuildsDeleted after delete on Builds execute procedure notifyBuildsDeleted();
create function notifyBuildRestarted() returns trigger as 'begin notify builds_restarted; return null; end;' language plpgsql;
create trigger BuildRestarted after update on Builds for each row
when (old.finished = 1 and new.finished = 0) execute procedure notifyBuildRestarted();
create function notifyBuildCancelled() returns trigger as 'begin notify builds_cancelled; return null; end;' language plpgsql;
create trigger BuildCancelled after update on Builds for each row
when (old.finished = 0 and new.finished = 1 and new.buildStatus = 4) execute procedure notifyBuildCancelled();
create function notifyBuildBumped() returns trigger as 'begin notify builds_bumped; return null; end;' language plpgsql;
create trigger BuildBumped after update on Builds for each row
when (old.globalPriority != new.globalPriority) execute procedure notifyBuildBumped();
create table BuildOutputs (
build integer not null,
name text not null,
path text not null,
primary key (build, name),
foreign key (build) references Builds(id) on delete cascade
);
create table BuildSteps (
build integer not null,
stepnr integer not null,
type integer not null,
drvPath text,
busy integer not null,
status integer,
errorMsg text,
startTime integer,
stopTime integer,
machine text not null default '',
system text,
propagatedFrom integer,
overhead integer,
timesBuilt integer,
isNonDeterministic boolean,
primary key (build, stepnr),
foreign key (build) references Builds(id) on delete cascade,
foreign key (propagatedFrom) references Builds(id) on delete cascade
);
create table BuildStepOutputs (
build integer not null,
stepnr integer not null,
name text not null,
path text not null,
primary key (build, stepnr, name),
foreign key (build) references Builds(id) on delete cascade,
foreign key (build, stepnr) references BuildSteps(build, stepnr) on delete cascade
);
create table BuildInputs (
id serial primary key not null,
build integer,
name text not null,
type text not null,
uri text,
revision text,
value text,
emailResponsible integer not null default 0,
dependency integer,
path text,
sha256hash text,
foreign key (build) references Builds(id) on delete cascade,
foreign key (dependency) references Builds(id)
);
create table BuildProducts (
build integer not null,
productnr integer not null,
type text not null, subtype text not null, fileSize bigint,
sha256hash text,
path text,
name text not null, defaultPath text, primary key (build, productnr),
foreign key (build) references Builds(id) on delete cascade
);
create table BuildMetrics (
build integer not null,
name text not null,
unit text,
value double precision not null,
project text not null,
jobset text not null,
job text not null,
timestamp integer not null,
primary key (build, name),
foreign key (build) references Builds(id) on delete cascade,
foreign key (project) references Projects(name) on update cascade,
foreign key (project, jobset) references Jobsets(project, name) on update cascade
);
create table CachedPathInputs (
srcPath text not null,
timestamp integer not null, lastSeen integer not null, sha256hash text not null,
storePath text not null,
primary key (srcPath, sha256hash)
);
create table CachedSubversionInputs (
uri text not null,
revision integer not null,
sha256hash text not null,
storePath text not null,
primary key (uri, revision)
);
create table CachedBazaarInputs (
uri text not null,
revision integer not null,
sha256hash text not null,
storePath text not null,
primary key (uri, revision)
);
create table CachedGitInputs (
uri text not null,
branch text not null,
revision text not null,
isDeepClone boolean not null,
sha256hash text not null,
storePath text not null,
primary key (uri, branch, revision, isDeepClone)
);
create table CachedDarcsInputs (
uri text not null,
revision text not null,
sha256hash text not null,
storePath text not null,
revCount integer not null,
primary key (uri, revision)
);
create table CachedHgInputs (
uri text not null,
branch text not null,
revision text not null,
sha256hash text not null,
storePath text not null,
primary key (uri, branch, revision)
);
create table CachedCVSInputs (
uri text not null,
module text not null,
timestamp integer not null, lastSeen integer not null, sha256hash text not null,
storePath text not null,
primary key (uri, module, sha256hash)
);
create table EvaluationErrors (
id serial primary key not null,
errorMsg text, errorTime integer );
create table JobsetEvals (
id serial primary key not null,
jobset_id integer not null,
evaluationerror_id integer,
timestamp integer not null, checkoutTime integer not null, evalTime integer not null,
hasNewBuilds integer not null,
hash text not null,
nrBuilds integer,
nrSucceeded integer,
flake text, nixExprInput text, nixExprPath text,
foreign key (jobset_id) references Jobsets(id) on delete cascade,
foreign key (evaluationerror_id) references EvaluationErrors(id) on delete set null
);
create table JobsetEvalInputs (
eval integer not null references JobsetEvals(id) on delete cascade,
name text not null,
altNr integer not null,
type text not null,
uri text,
revision text,
value text,
dependency integer,
path text,
sha256hash text,
primary key (eval, name, altNr),
foreign key (dependency) references Builds(id)
);
create table JobsetEvalMembers (
eval integer not null references JobsetEvals(id) on delete cascade,
build integer not null references Builds(id) on delete cascade,
isNew integer not null,
primary key (eval, build)
);
create table UriRevMapper (
baseuri text not null,
uri text not null,
primary key (baseuri)
);
create table NewsItems (
id serial primary key not null,
contents text not null,
createTime integer not null,
author text not null,
foreign key (author) references Users(userName) on delete cascade on update cascade
);
create table AggregateConstituents (
aggregate integer not null references Builds(id) on delete cascade,
constituent integer not null references Builds(id) on delete cascade,
primary key (aggregate, constituent)
);
create table StarredJobs (
userName text not null,
project text not null,
jobset text not null,
job text not null,
primary key (userName, project, jobset, job),
foreign key (userName) references Users(userName) on update cascade on delete cascade,
foreign key (project) references Projects(name) on update cascade on delete cascade,
foreign key (project, jobset) references Jobsets(project, name) on update cascade on delete cascade
);
create table TaskRetries (
id serial primary key not null,
channel text not null,
pluginname text not null,
payload text not null,
attempts integer not null,
retry_at integer not null
);
create index IndexTaskRetriesOrdered on TaskRetries(retry_at asc);
create table RunCommandLogs (
id serial primary key not null,
job_matcher text not null,
build_id integer not null,
command text not null,
start_time integer,
end_time integer,
error_number integer,
exit_code integer,
signal integer,
core_dumped boolean,
foreign key (build_id) references Builds(id) on delete cascade,
constraint RunCommandLogs_not_started_no_exit_time_no_code check (
(start_time is not null) or (
end_time is null
and error_number is null
and exit_code is null
and signal is null
and core_dumped is null
)
),
constraint RunCommandLogs_end_time_has_start_time check (
(end_time is null) or (start_time is not null)
)
);
create table FailedPaths (
path text primary key not null
);
create rule IdempotentInsert as on insert to FailedPaths
where exists (select 1 from FailedPaths where path = new.path)
do instead nothing;
create table SystemStatus (
what text primary key not null,
status json not null
);
create table NrBuilds (
what text primary key not null,
count integer not null
);
insert into NrBuilds(what, count) values('finished', 0);
create function modifyNrBuildsFinished() returns trigger as $$
begin
if ((tg_op = 'INSERT' and new.finished = 1) or
(tg_op = 'UPDATE' and old.finished = 0 and new.finished = 1)) then
update NrBuilds set count = count + 1 where what = 'finished';
elsif ((tg_op = 'DELETE' and old.finished = 1) or
(tg_op = 'UPDATE' and old.finished = 1 and new.finished = 0)) then
update NrBuilds set count = count - 1 where what = 'finished';
end if;
return null;
end;
$$ language plpgsql;
create trigger NrBuildsFinished after insert or update or delete on Builds
for each row
execute procedure modifyNrBuildsFinished();
create index IndexBuildInputsOnBuild on BuildInputs(build);
create index IndexBuildInputsOnDependency on BuildInputs(dependency);
create index IndexBuildMetricsOnJobTimestamp on BuildMetrics(project, jobset, job, timestamp desc);
create index IndexBuildProducstOnBuildAndType on BuildProducts(build, type);
create index IndexBuildProductsOnBuild on BuildProducts(build);
create index IndexBuildStepsOnBusy on BuildSteps(busy) where busy != 0;
create index IndexBuildStepsOnDrvPath on BuildSteps(drvpath);
create index IndexBuildStepsOnPropagatedFrom on BuildSteps(propagatedFrom) where propagatedFrom is not null;
create index IndexBuildStepsOnStopTime on BuildSteps(stopTime desc) where startTime is not null and stopTime is not null;
create index IndexBuildStepOutputsOnPath on BuildStepOutputs(path);
create index IndexBuildsOnFinished on Builds(finished) where finished = 0;
create index IndexBuildsOnIsCurrent on Builds(isCurrent) where isCurrent = 1;
create index IndexBuildsJobsetIdCurrentUnfinished on Builds(jobset_id) where isCurrent = 1 and finished = 0;
create index IndexBuildsJobsetIdCurrentFinishedStatus on Builds(jobset_id, buildstatus) where isCurrent = 1 and finished = 1;
create index IndexBuildsJobsetIdCurrent on Builds(jobset_id) where isCurrent = 1;
create index IndexBuildsOnTimestamp on Builds(timestamp);
create index IndexBuildsOnFinishedStopTime on Builds(finished, stoptime DESC);
create index IndexBuildsOnJobsetIdFinishedId on Builds(jobset_id, job, finished, id DESC);
create index IndexFinishedSuccessfulBuilds on Builds(jobset_id, job, finished, buildstatus, id DESC) where buildstatus = 0 and finished = 1;
create index IndexBuildsOnDrvPath on Builds(drvPath);
create index IndexCachedHgInputsOnHash on CachedHgInputs(uri, branch, sha256hash);
create index IndexCachedGitInputsOnHash on CachedGitInputs(uri, branch, sha256hash);
create index IndexCachedSubversionInputsOnUriRevision on CachedSubversionInputs(uri, revision);
create index IndexCachedBazaarInputsOnUriRevision on CachedBazaarInputs(uri, revision);
create index IndexJobsetEvalMembersOnBuild on JobsetEvalMembers(build);
create index IndexJobsetEvalMembersOnEval on JobsetEvalMembers(eval);
create index IndexJobsetInputAltsOnInput on JobsetInputAlts(project, jobset, input);
create index IndexJobsetInputAltsOnJobset on JobsetInputAlts(project, jobset);
create index IndexProjectsOnEnabled on Projects(enabled);
create index IndexBuildOutputsPath on BuildOutputs using hash(path);
create index IndexBuildsOnKeep on Builds(keep) where keep = 1;
create index IndexJobsetEvalsOnJobsetId on JobsetEvals(jobset_id, id desc) where hasNewBuilds = 1;
create index IndexJobsetIdEvals on JobsetEvals(jobset_id) where hasNewBuilds = 1;
create index IndexBuildsOnNotificationPendingSince on Builds(notificationPendingSince) where notificationPendingSince is not null;
do $$
begin
create extension if not exists pg_trgm;
create index IndexTrgmBuildsOnDrvpath on builds using gin (drvpath gin_trgm_ops);
exception when others then
raise warning 'Can not create extension pg_trgm: %', SQLERRM;
raise warning 'HINT: Temporary provide superuser role to your Hydra Postgresql user and run the script src/sql/upgrade-57.sql';
raise warning 'The pg_trgm index on builds.drvpath has been skipped (slower complex queries on builds.drvpath)';
end$$;