diff --git a/backend/daemon/storage/migrations.go b/backend/daemon/storage/migrations.go index 2926d285f..2185d2f74 100644 --- a/backend/daemon/storage/migrations.go +++ b/backend/daemon/storage/migrations.go @@ -416,18 +416,41 @@ var migrations = []migration{ }}, {Version: "2024-03-25.01", Run: func(_ *Dir, conn *sqlite.Conn) error { return sqlitex.ExecScript(conn, sqlfmt(` - DROP VIEW IF EXISTS meta_view; - CREATE VIEW if not exists meta_view AS - SELECT sb.meta, resources.iri, public_keys.principal - FROM structural_blobs sb - JOIN public_keys ON public_keys.id = sb.author - JOIN resources ON resources.id = sb.resource - JOIN ( - SELECT resource, MAX(ts) AS max_ts - FROM structural_blobs - WHERE type='Change' AND meta IS NOT NULL - GROUP BY resource - ) AS latest_blobs ON sb.resource = latest_blobs.resource AND sb.ts = latest_blobs.max_ts; + DROP VIEW IF EXISTS meta_view; + CREATE VIEW if not exists meta_view AS + WITH RankedBlobs AS ( + SELECT + sb.id, + sb.meta, + sb.author, + sb.resource, + sb.ts, + ROW_NUMBER() OVER ( + PARTITION BY sb.resource + ORDER BY + (CASE WHEN sb.meta IS NOT NULL THEN 0 ELSE 1 END), + sb.ts DESC + ) AS rank + FROM structural_blobs sb + WHERE sb.type = 'Change' + ), + LatestBlobs AS ( + SELECT + rb.id, + rb.meta, + rb.author, + rb.resource, + rb.ts + FROM RankedBlobs rb + WHERE rb.rank = 1 + ) + SELECT + lb.meta, + res.iri, + pk.principal + FROM LatestBlobs lb + JOIN resources res ON res.id = lb.resource + JOIN public_keys pk ON pk.id = lb.author; `)) }}, } diff --git a/backend/daemon/storage/schema.gensum b/backend/daemon/storage/schema.gensum index 6f124c386..1b01b9ecf 100644 --- a/backend/daemon/storage/schema.gensum +++ b/backend/daemon/storage/schema.gensum @@ -1,2 +1,2 @@ -srcs: c0bb41a9dd9db2130a02aa83b977269f -outs: 0efc08608cead13c5b8756e4beee2ecd +srcs: 8f7984b962c288b761a8346ebfcab040 +outs: 67a994f0ff45ef5e3e3e60482412dc96 diff --git a/backend/daemon/storage/schema.sql b/backend/daemon/storage/schema.sql index 264d3173f..7ff9ef08e 100644 --- a/backend/daemon/storage/schema.sql +++ b/backend/daemon/storage/schema.sql @@ -82,7 +82,7 @@ JOIN blobs ON blobs.id = structural_blobs.id JOIN resources ON structural_blobs.resource = resources.id; -- View blobs metadata It returns the latest non null title or the --- latest blob in case of untitled. +-- latest blob in case of untitled meta. CREATE VIEW meta_view AS WITH RankedBlobs AS ( SELECT