Skip to content

Commit 64ab73a

Browse files
authored
Merge pull request #994 from ellemouton/sql21Sessions13
[sql-21] sessions: SQL schemas & queries
2 parents 66e8de9 + 2016766 commit 64ab73a

File tree

7 files changed

+1028
-1
lines changed

7 files changed

+1028
-1
lines changed

db/migrations.go

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -22,7 +22,7 @@ const (
2222
// daemon.
2323
//
2424
// NOTE: This MUST be updated when a new migration is added.
25-
LatestMigrationVersion = 1
25+
LatestMigrationVersion = 2
2626
)
2727

2828
// MigrationTarget is a functional option that can be passed to applyMigrations
Lines changed: 12 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,12 @@
1+
DROP INDEX IF EXISTS sessions_type_idx;
2+
DROP INDEX IF EXISTS sessions_group_id_idx;
3+
DROP INDEX IF EXISTS session_feature_configs_unique;
4+
DROP INDEX IF EXISTS session_priv_flags_unique;
5+
DROP INDEX IF EXISTS session_mac_perms_idx;
6+
DROP INDEX IF EXISTS sessions_mac_caveats_idx;
7+
DROP INDEX IF EXISTS sessions_state_idx;
8+
DROP TABLE IF EXISTS session_macaroon_permissions;
9+
DROP TABLE IF EXISTS session_macaroon_caveats;
10+
DROP TABLE IF EXISTS session_feature_configs;
11+
DROP TABLE IF EXISTS session_privacy_flags;
12+
DROP TABLE IF EXISTS sessions;
Lines changed: 144 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,144 @@
1+
-- The sessions table contains LNC session related information.
2+
CREATE TABLE IF NOT EXISTS sessions (
3+
-- The auto incrementing primary key.
4+
id INTEGER PRIMARY KEY,
5+
6+
-- The ID that was used to identify the session in the legacy KVDB store.
7+
-- This is derived directly from the local_public_key. In order to avoid
8+
-- breaking the API, we keep this field here so that we can still look up
9+
-- sessions by this ID.
10+
alias BLOB NOT NULL UNIQUE,
11+
12+
-- The session's given label.
13+
label TEXT NOT NULL,
14+
15+
-- The session's current state.
16+
state SMALLINT NOT NULL,
17+
18+
-- The session type.
19+
type SMALLINT NOT NULL,
20+
21+
-- expiry is the time that the session will expire.
22+
expiry TIMESTAMP NOT NULL,
23+
24+
-- The session's creation time.
25+
created_at TIMESTAMP NOT NULL,
26+
27+
-- The time at which the session was revoked.
28+
revoked_at TIMESTAMP,
29+
30+
-- The mailbox server address.
31+
server_address TEXT NOT NULL,
32+
33+
-- Whether the connection to the server should not use TLS.
34+
dev_server BOOLEAN NOT NULL,
35+
36+
-- The root key ID to use when baking a macaroon for this session.
37+
macaroon_root_key BIGINT NOT NULL,
38+
39+
-- The passphrase entropy to use when deriving the mnemonic for this LNC
40+
-- session.
41+
pairing_secret BLOB NOT NULL,
42+
43+
-- The private key of the long term local static key for this LNC session.
44+
local_private_key BLOB NOT NULL,
45+
46+
-- The public key of the long term local static key for this LNC session.
47+
-- This is derivable from the local_private_key but is stored here since
48+
-- the local public key was used to identify a session when the DB was KVDB
49+
-- based and so to keep the API consistent, we store it here so that we can
50+
-- still look up sessions by this public key.
51+
local_public_key BLOB NOT NULL UNIQUE,
52+
53+
-- The public key of the long term remote static key for this LNC session.
54+
remote_public_key BLOB,
55+
56+
-- Whether the privacy mapper should be used for this session.
57+
privacy BOOLEAN NOT NULL,
58+
59+
-- An optional account ID that this session is linked to.
60+
account_id BIGINT REFERENCES accounts(id) ON DELETE CASCADE,
61+
62+
-- The session ID of the first session in this linked session group. This
63+
-- is nullable for the case where the first session in the group is being
64+
-- inserted, and so we first need to insert the session before we know the
65+
-- ID to use for the group ID.
66+
group_id BIGINT REFERENCES sessions(id) ON DELETE CASCADE
67+
);
68+
69+
CREATE INDEX IF NOT EXISTS sessions_type_idx ON sessions(type);
70+
CREATE INDEX IF NOT EXISTS sessions_state_idx ON sessions(state);
71+
CREATE INDEX IF NOT EXISTS sessions_group_id_idx ON sessions(group_id);
72+
73+
-- The session_macaroon_permissions table contains the macaroon permissions
74+
-- that are associated with a session.
75+
CREATE TABLE IF NOT EXISTS session_macaroon_permissions (
76+
-- The auto incrementing primary key.
77+
id INTEGER PRIMARY KEY,
78+
79+
-- The ID of the session in the sessions table that this permission is
80+
-- associated with.
81+
session_id BIGINT NOT NULL REFERENCES sessions(id) ON DELETE CASCADE,
82+
83+
-- The entity that this permission is for.
84+
entity TEXT NOT NULL,
85+
86+
-- The action that this permission is for.
87+
action TEXT NOT NULL
88+
);
89+
CREATE INDEX IF NOT EXISTS sessions_mac_perms_idx ON session_macaroon_permissions(session_id);
90+
91+
-- The session_macaroon_caveats table contains the macaroon caveats that are
92+
-- associated with a session.
93+
CREATE TABLE IF NOT EXISTS session_macaroon_caveats (
94+
-- The auto incrementing primary key.
95+
id INTEGER PRIMARY KEY,
96+
97+
-- The ID of the session in the sessions table that this caveat is
98+
-- associated with.
99+
session_id BIGINT NOT NULL REFERENCES sessions(id) ON DELETE CASCADE,
100+
101+
-- The caveat ID.
102+
caveat_id BLOB NOT NULL,
103+
104+
-- The verification ID. If this is not-null, it's a third party caveat.
105+
verification_id BLOB,
106+
107+
-- The location hint for third party caveats.
108+
location TEXT
109+
);
110+
111+
CREATE INDEX IF NOT EXISTS sessions_mac_caveats_idx ON session_macaroon_caveats(session_id);
112+
113+
-- The session_feature_configs table contains the feature configs that are
114+
-- associated with a session.
115+
CREATE TABLE IF NOT EXISTS session_feature_configs (
116+
-- The ID of the session in the sessions table that this feature config is
117+
-- associated with.
118+
session_id BIGINT NOT NULL REFERENCES sessions(id) ON DELETE CASCADE,
119+
120+
-- The feature name.
121+
feature_name TEXT NOT NULL,
122+
123+
-- The feature config blob.
124+
config BLOB
125+
);
126+
127+
CREATE UNIQUE INDEX session_feature_configs_unique ON session_feature_configs (
128+
session_id, feature_name
129+
);
130+
131+
-- The session_privacy_flags table contains the privacy flags that are
132+
-- associated with a session.
133+
CREATE TABLE IF NOT EXISTS session_privacy_flags (
134+
-- The ID of the session in the sessions table that this privacy bit is
135+
-- associated with.
136+
session_id BIGINT NOT NULL REFERENCES sessions(id) ON DELETE CASCADE,
137+
138+
-- The privacy flag bit.
139+
flag INTEGER NOT NULL
140+
);
141+
142+
CREATE UNIQUE INDEX session_priv_flags_unique ON session_privacy_flags (
143+
session_id, flag
144+
);

db/sqlc/models.go

Lines changed: 47 additions & 0 deletions
Some generated files are not rendered by default. Learn more about customizing how changed files appear on GitHub.

db/sqlc/querier.go

Lines changed: 24 additions & 0 deletions
Some generated files are not rendered by default. Learn more about customizing how changed files appear on GitHub.

db/sqlc/queries/sessions.sql

Lines changed: 120 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,120 @@
1+
-- name: InsertSession :one
2+
INSERT INTO sessions (
3+
alias, label, state, type, expiry, created_at,
4+
server_address, dev_server, macaroon_root_key, pairing_secret,
5+
local_private_key, local_public_key, remote_public_key, privacy, group_id, account_id
6+
) VALUES (
7+
$1, $2, $3, $4, $5, $6, $7,
8+
$8, $9, $10, $11, $12,
9+
$13, $14, $15, $16
10+
) RETURNING id;
11+
12+
-- name: SetSessionGroupID :exec
13+
UPDATE sessions
14+
SET group_id = $1
15+
WHERE id = $2;
16+
17+
-- name: DeleteSessionsWithState :exec
18+
DELETE FROM sessions
19+
WHERE state = $1;
20+
21+
-- name: GetSessionByLocalPublicKey :one
22+
SELECT * FROM sessions
23+
WHERE local_public_key = $1;
24+
25+
-- name: GetSessionsInGroup :many
26+
SELECT * FROM sessions
27+
WHERE group_id = $1;
28+
29+
-- name: GetSessionAliasesInGroup :many
30+
SELECT alias FROM sessions
31+
WHERE group_id = $1;
32+
33+
-- name: GetSessionByID :one
34+
SELECT * FROM sessions
35+
WHERE id = $1;
36+
37+
-- name: GetSessionIDByAlias :one
38+
SELECT id FROM sessions
39+
WHERE alias = $1;
40+
41+
-- name: GetAliasBySessionID :one
42+
SELECT alias FROM sessions
43+
WHERE id = $1;
44+
45+
-- name: GetSessionByAlias :one
46+
SELECT * FROM sessions
47+
WHERE alias = $1;
48+
49+
-- name: ListSessions :many
50+
SELECT * FROM sessions
51+
ORDER BY created_at;
52+
53+
-- name: ListSessionsByType :many
54+
SELECT * FROM sessions
55+
WHERE type = $1
56+
ORDER BY created_at;
57+
58+
-- name: ListSessionsByState :many
59+
SELECT * FROM sessions
60+
WHERE state = $1
61+
ORDER BY created_at;
62+
63+
-- name: SetSessionRevokedAt :exec
64+
UPDATE sessions
65+
SET revoked_at = $1
66+
WHERE id = $2;
67+
68+
-- name: UpdateSessionState :exec
69+
UPDATE sessions
70+
SET state = $1
71+
WHERE id = $2;
72+
73+
-- name: SetSessionRemotePublicKey :exec
74+
UPDATE sessions
75+
SET remote_public_key = $1
76+
WHERE id = $2;
77+
78+
-- name: InsertSessionMacaroonPermission :exec
79+
INSERT INTO session_macaroon_permissions (
80+
session_id, entity, action
81+
) VALUES (
82+
$1, $2, $3
83+
);
84+
85+
-- name: GetSessionMacaroonPermissions :many
86+
SELECT * FROM session_macaroon_permissions
87+
WHERE session_id = $1;
88+
89+
-- name: InsertSessionMacaroonCaveat :exec
90+
INSERT INTO session_macaroon_caveats (
91+
session_id, caveat_id, verification_id, location
92+
) VALUES (
93+
$1, $2, $3, $4
94+
);
95+
96+
-- name: GetSessionMacaroonCaveats :many
97+
SELECT * FROM session_macaroon_caveats
98+
WHERE session_id = $1;
99+
100+
-- name: InsertSessionFeatureConfig :exec
101+
INSERT INTO session_feature_configs (
102+
session_id, feature_name, config
103+
) VALUES (
104+
$1, $2, $3
105+
);
106+
107+
-- name: GetSessionFeatureConfigs :many
108+
SELECT * FROM session_feature_configs
109+
WHERE session_id = $1;
110+
111+
-- name: InsertSessionPrivacyFlag :exec
112+
INSERT INTO session_privacy_flags (
113+
session_id, flag
114+
) VALUES (
115+
$1, $2
116+
);
117+
118+
-- name: GetSessionPrivacyFlags :many
119+
SELECT * FROM session_privacy_flags
120+
WHERE session_id = $1;

0 commit comments

Comments
 (0)