database: Store work parts in seperate table

This commit is contained in:
Elias Projahn 2020-05-13 18:57:50 +02:00
parent 2d96d2fec8
commit 9bd0348f35
3 changed files with 64 additions and 41 deletions

View file

@ -97,17 +97,18 @@ class Database extends _$Database {
Future<WorkInfo> getWorkInfo(Work work) async {
final id = work.id;
final composers = await composersByWork(id).get();
final composers = await partComposersByWork(id).get();
composers.insert(0, await personById(work.composer).getSingle());
final instruments = await instrumentsByWork(id).get();
final List<PartInfo> parts = [];
for (final part in await workParts(id).get()) {
for (final part in await partsByWork(id).get()) {
parts.add(PartInfo(
work: part,
part: part,
composer: part.composer != null
? await personById(part.composer).getSingle()
: null,
instruments: await instrumentsByWork(id).get(),
instruments: await instrumentsByWorkPart(part.id).get(),
));
}
@ -163,32 +164,35 @@ class Database extends _$Database {
// deleted automatically due to their foreign key constraints.
await deleteWork(workId);
/// Insert instrumentations for a work.
///
/// At the moment, this will also update all provided instruments, even
/// if they were already there previously.
Future<void> insertInstrumentations(
int workId, List<Instrument> instruments) async {
for (final instrument in instruments) {
await updateInstrument(instrument);
await into(instrumentations).insert(Instrumentation(
work: workId,
instrument: instrument.id,
));
}
}
// This will also include the composers of the work's parts.
for (final person in workInfo.composers) {
await updatePerson(person);
}
await into(works).insert(workInfo.work);
await insertInstrumentations(workId, workInfo.instruments);
// At the moment, this will also update all provided instruments, even if
// they were already there previously.
for (final instrument in workInfo.instruments) {
await updateInstrument(instrument);
await into(instrumentations).insert(Instrumentation(
work: workId,
instrument: instrument.id,
));
}
for (final partInfo in workInfo.parts) {
await into(works).insert(partInfo.work);
await insertInstrumentations(partInfo.work.id, partInfo.instruments);
final part = partInfo.part;
await into(workParts).insert(part);
for (final instrument in workInfo.instruments) {
await updateInstrument(instrument);
await into(partInstrumentations).insert(PartInstrumentation(
workPart: part.id,
instrument: instrument.id,
));
}
}
});
}

View file

@ -14,9 +14,7 @@ CREATE TABLE instruments (
CREATE TABLE works (
id INTEGER NOT NULL PRIMARY KEY,
composer INTEGER REFERENCES persons(id) ON DELETE SET NULL,
title TEXT NOT NULL,
part_of INTEGER REFERENCES works(id) ON DELETE CASCADE,
part_index INTEGER
title TEXT NOT NULL
);
CREATE TABLE instrumentations (
@ -24,6 +22,19 @@ CREATE TABLE instrumentations (
instrument INTEGER NOT NULL REFERENCES instruments(id) ON DELETE CASCADE
);
CREATE TABLE work_parts (
id INTEGER NOT NULL PRIMARY KEY,
composer INTEGER REFERENCES persons(id) ON DELETE SET NULL,
title TEXT NOT NULL,
part_of INTEGER NOT NULL REFERENCES works(id) ON DELETE CASCADE,
part_index INTEGER NOT NULL
);
CREATE TABLE part_instrumentations (
work_part INTEGER NOT NULL REFERENCES works(id) ON DELETE CASCADE,
instrument INTEGER NOT NULL REFERENCES instruments(id) ON DELETE CASCADE
);
CREATE TABLE ensembles (
id INTEGER NOT NULL PRIMARY KEY,
name TEXT NOT NULL
@ -66,29 +77,37 @@ SELECT * FROM instruments WHERE id = :id LIMIT 1;
workById:
SELECT * FROM works WHERE id = :id LIMIT 1;
workParts:
SELECT * FROM works WHERE part_of = :id ORDER BY part_index;
partsByWork:
SELECT * FROM work_parts WHERE part_of = :id ORDER BY part_index;
worksByComposer:
SELECT DISTINCT A.* FROM works A LEFT JOIN works B ON A.id = B.part_of
WHERE (A.part_of IS NULL AND A.composer = :id) OR B.composer = :id
ORDER BY A.title LIMIT :limit OFFSET :offset;
SELECT DISTINCT works.* FROM works
JOIN work_parts ON work_parts.part_of = works.id
WHERE works.composer = :id OR work_parts.composer = :id
ORDER BY works.title LIMIT :limit OFFSET :offset;
searchWorksByComposer:
SELECT DISTINCT A.* FROM works A LEFT JOIN works B ON A.id = B.part_of
WHERE ((A.part_of IS NULL AND A.composer = :id) OR B.composer = :id)
AND A.title LIKE :search ORDER BY A.title LIMIT :limit OFFSET :offset;
SELECT DISTINCT works.* FROM works
JOIN work_parts ON work_parts.part_of = works.id
WHERE (works.composer = :id OR work_parts.composer = :id)
AND works.title LIKE :search
ORDER BY works.title LIMIT :limit OFFSET :offset;
composersByWork:
partComposersByWork:
SELECT DISTINCT persons.* FROM persons
JOIN works ON works.composer = persons.id
WHERE works.id = :id OR works.part_of = :id;
JOIN work_parts ON work_parts.composer = persons.id
WHERE work_parts.part_of = :id;
instrumentsByWork:
SELECT instruments.* FROM instrumentations
JOIN instruments ON instrumentations.instrument=instruments.id
JOIN instruments ON instrumentations.instrument = instruments.id
WHERE instrumentations.work = :workId;
instrumentsByWorkPart:
SELECT instruments.* FROM part_instrumentations
JOIN instruments ON part_instrumentations.instrument = instruments.id
WHERE part_instrumentations.work_part = :id;
allEnsembles:
SELECT * FROM ensembles ORDER BY name LIMIT :limit OFFSET :offset;

View file

@ -3,7 +3,7 @@ import 'database.dart';
/// A bundle of all available information on a work part.
class PartInfo {
/// The work part itself.
final Work work;
final WorkPart part;
/// A list of instruments.
///
@ -16,13 +16,13 @@ class PartInfo {
final Person composer;
PartInfo({
this.work,
this.part,
this.instruments,
this.composer,
});
factory PartInfo.fromJson(Map<String, dynamic> json) => PartInfo(
work: Work.fromJson(json['work']),
part: WorkPart.fromJson(json['part']),
instruments: json['instruments']
.map<Instrument>((j) => Instrument.fromJson(j))
.toList(),
@ -31,7 +31,7 @@ class PartInfo {
);
Map<String, dynamic> toJson() => {
'work': work.toJson(),
'part': part.toJson(),
'instruments': instruments.map((i) => i.toJson()).toList(),
'composers': composer?.toJson(),
};