ca: add sqlite index on RealisationsRefs(realisationReference)
Without the change any CA deletion triggers linear scan on large RealisationsRefs table: sqlite>.eqp full sqlite> delete from RealisationsRefs where realisationReference IN ( select id from Realisations where outputPath = 1234567890 ); QUERY PLAN |--SCAN RealisationsRefs `--LIST SUBQUERY 1 `--SEARCH Realisations USING COVERING INDEX IndexRealisationsRefsOnOutputPath (outputPath=?) With the change it gets turned into a lookup: sqlite> CREATE INDEX IndexRealisationsRefsRealisationReference on RealisationsRefs(realisationReference); sqlite> delete from RealisationsRefs where realisationReference IN ( select id from Realisations where outputPath = 1234567890 ); QUERY PLAN |--SEARCH RealisationsRefs USING INDEX IndexRealisationsRefsRealisationReference (realisationReference=?) `--LIST SUBQUERY 1 `--SEARCH Realisations USING COVERING INDEX IndexRealisationsRefsOnOutputPath (outputPath=?)
This commit is contained in:
parent
b6e59d7137
commit
975b0b52e7
|
@ -32,6 +32,8 @@ create table if not exists RealisationsRefs (
|
|||
foreign key (referrer) references Realisations(id) on delete cascade,
|
||||
foreign key (realisationReference) references Realisations(id) on delete restrict
|
||||
);
|
||||
-- used by deletion trigger
|
||||
create index if not exists IndexRealisationsRefsRealisationReference on RealisationsRefs(realisationReference);
|
||||
|
||||
-- used by QueryRealisationReferences
|
||||
create index if not exists IndexRealisationsRefs on RealisationsRefs(referrer);
|
||||
|
|
|
@ -152,6 +152,8 @@ void migrateCASchema(SQLite& db, Path schemaPath, AutoCloseFD& lockFd)
|
|||
select id from Realisations where outputPath = old.id
|
||||
);
|
||||
end;
|
||||
-- used by deletion trigger
|
||||
create index if not exists IndexRealisationsRefsRealisationReference on RealisationsRefs(realisationReference);
|
||||
)");
|
||||
txn.commit();
|
||||
}
|
||||
|
|
Loading…
Reference in a new issue