summaryrefslogtreecommitdiff
path: root/migrations/20240928002608_channel_lifecycle.sql
blob: bc690d79dd07b59786b125784026477f23b39902 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
alter table channel
rename to old_channel;

-- Add new columns
create table channel (
	id text
		not null
		primary key,
	name text
		not null
		unique,
	created_at text
		not null
);

-- Transfer data from original table
insert into channel
select
	channel.id,
	channel.name,
	coalesce(
		min(message.sent_at),
		strftime('%FT%R:%f+00:00', 'now', 'utc')
	) as created_at
from old_channel as channel
	left join message on channel.id = message.channel
group by channel.id, channel.name;

-- Fix up `message` foreign keys
alter table message
rename to old_message;

create table message (
	id text
		not null
		primary key,
	sequence bigint
		not null,
	channel text
		not null
		references channel (id),
	sender text
		not null
		references login (id),
	body text
		not null,
	sent_at text
		not null,
	unique (channel, sequence)
);

insert into message
select * from old_message;

-- Bury the bodies respectfully
drop table old_message;
drop table old_channel;