Skip to content

Commit c33c9fd

Browse files
authored
feat(cat-gateway): Add a signed documents repository storage table in the Event DB (#1322)
* refactor(cat-gateway): Move unused schemas out of the main schema directory * feat(cat-gateway): Add signed documents repository table to the postgresql DB. * feat(cat-gateway): Add author, and more indexes to the signed docs repository table * fix(cat-gateway): BYTEA not BLOB * fix(cat-gateway): move unused migrations out of the migrations folder * fix(cat-gateway): Fix comment annotations to refer to correct table * fix(cat-gateway): fix index names in the comments
1 parent 46f7344 commit c33c9fd

File tree

6 files changed

+63
-0
lines changed

6 files changed

+63
-0
lines changed
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,63 @@
1+
-- Catalyst Voices Database - Signed Documents Repository
2+
-- sqlfluff:dialect:postgres
3+
4+
-- Title : Signed Documents Repository
5+
6+
-- Signed Documents Repository Tables
7+
8+
-- Note: ULID are stored using the native postgresql UUID type, as they are the same size.
9+
-- See: https://blog.daveallie.com/ulid-primary-keys/ for a description of this approach.
10+
11+
-- -------------------------------------------------------------------------------------------------
12+
13+
-- Signed Documents Storage Repository defintion.
14+
CREATE TABLE IF NOT EXISTS signed_docs (
15+
id UUID NOT NULL, -- Actually a ULID
16+
ver UUID NOT NULL, -- Actually a ULID
17+
type UUID NOT NULL, -- Yes its a UUID this time
18+
author TEXT NOT NULL,
19+
metadata JSONB NOT NULL,
20+
payload JSONB NULL,
21+
raw BYTEA NOT NULL,
22+
23+
CONSTRAINT pk PRIMARY KEY (id, ver)
24+
);
25+
26+
COMMENT ON TABLE signed_docs IS
27+
'Storage for Signed Documents.';
28+
29+
COMMENT ON COLUMN signed_docs.id IS
30+
'The Signed Documents Document ID (ULID).';
31+
COMMENT ON COLUMN signed_docs.ver IS
32+
'The Signed Documents Document Version Number (ULID).';
33+
COMMENT ON COLUMN signed_docs.type IS
34+
'The Signed Document type identifier.';
35+
COMMENT ON COLUMN signed_docs.author IS
36+
'The Primary Author of the Signed Document.';
37+
COMMENT ON COLUMN signed_docs.metadata IS
38+
'Extra metadata extracted from the Signed Document, and encoded as JSON.';
39+
COMMENT ON COLUMN signed_docs.payload IS
40+
'IF the document has a compressed json payload, the uncompressed json payload is stored here.';
41+
COMMENT ON COLUMN signed_docs.raw IS
42+
'The RAW unaltered signed document, including its signatures, and full COSE envelope.';
43+
44+
CREATE INDEX IF NOT EXISTS idx_signed_docs_type ON signed_docs (type);
45+
COMMENT ON INDEX idx_signed_docs_type IS
46+
'Index to help finding documents by a known type faster.';
47+
48+
CREATE INDEX IF NOT EXISTS idx_signed_docs_author ON signed_docs (author);
49+
COMMENT ON INDEX idx_signed_docs_author IS
50+
'Index to help finding documents by a known author faster.';
51+
52+
CREATE INDEX IF NOT EXISTS idx_signed_docs_type_author ON signed_docs (type, author);
53+
COMMENT ON INDEX idx_signed_docs_type_author IS
54+
'Index to help finding documents by a known author for a specific document type faster.';
55+
56+
57+
CREATE INDEX IF NOT EXISTS idx_signed_docs_metadata ON signed_docs USING gin (metadata);
58+
COMMENT ON INDEX idx_signed_docs_metadata IS
59+
'Index to help search metadata attached to the signed documents.';
60+
61+
CREATE INDEX IF NOT EXISTS idx_signed_docs_payload ON signed_docs USING gin (payload);
62+
COMMENT ON INDEX idx_signed_docs_payload IS
63+
'Index to help search payload data contained in a signed documents.';

0 commit comments

Comments
 (0)