init
This commit is contained in:
commit
1c9d89946a
4
.env.postgres
Normal file
4
.env.postgres
Normal file
@ -0,0 +1,4 @@
|
||||
POSTGRES_USER=admin
|
||||
POSTGRES_PASSWORD=admin
|
||||
POSTGRES_DB=chat
|
||||
PGDATA=/var/lib/postgresql/data/pgdata
|
23
docker-compose.yml
Normal file
23
docker-compose.yml
Normal file
@ -0,0 +1,23 @@
|
||||
services:
|
||||
database:
|
||||
image: postgres:17-alpine
|
||||
restart: unless-stopped
|
||||
ports:
|
||||
- 5432:5432
|
||||
env_file: .env.postgres
|
||||
volumes:
|
||||
- pgdata:/var/lib/postgresql/data
|
||||
- ./postgres:/docker-entrypoint-initdb.d:ro
|
||||
|
||||
keystore:
|
||||
image: valkey/valkey:8-alpine
|
||||
restart: unless-stopped
|
||||
ports:
|
||||
- 6379:6379
|
||||
command: valkey-server /usr/local/etc/valkey/valkey.conf
|
||||
volumes:
|
||||
- ./valkey/valkey.conf:/usr/local/etc/valkey/valkey.conf:ro
|
||||
- ./valkey/users.acl:/usr/local/etc/valkey/users.acl:ro
|
||||
|
||||
volumes:
|
||||
pgdata:
|
44
postgres/10-init.sql
Normal file
44
postgres/10-init.sql
Normal file
@ -0,0 +1,44 @@
|
||||
create table if not exists "user" (
|
||||
"id" serial primary key,
|
||||
"username" varchar(32) not null unique,
|
||||
"password_hash" varchar(72) not null,
|
||||
"status" varchar(200) not null default '',
|
||||
"picture" varchar(300) not null default '',
|
||||
"bio" varchar(200) not null default ''
|
||||
);
|
||||
|
||||
create table if not exists "role" (
|
||||
"id" serial primary key,
|
||||
"name" varchar(32) not null unique
|
||||
);
|
||||
|
||||
create table if not exists "role_binding" (
|
||||
"user_id" integer not null references "user"("id") on delete cascade,
|
||||
"role_id" integer not null references "role"("id") on delete cascade,
|
||||
primary key ("user_id", "role_id"),
|
||||
unique ("user_id", "role_id")
|
||||
);
|
||||
|
||||
create table if not exists "channel" (
|
||||
"id" serial primary key,
|
||||
"name" varchar(32) not null unique,
|
||||
"description" varchar(200) default null
|
||||
);
|
||||
|
||||
create type "right_t" as enum ('R', 'W', 'RW', 'A');
|
||||
|
||||
create table if not exists "right" (
|
||||
"role_id" integer not null references "role"("id"),
|
||||
"channel_id" integer not null references "channel"("id"),
|
||||
"rights" right_t not null,
|
||||
primary key ("role_id", "channel_id"),
|
||||
unique ("role_id", "channel_id")
|
||||
);
|
||||
|
||||
create table if not exists "message" (
|
||||
"id" serial primary key,
|
||||
"sender_id" integer not null references "user"("id") on delete cascade,
|
||||
"channel_id" integer not null references "channel"("id") on delete cascade,
|
||||
"time" timestamp without time zone default (now() at time zone 'utc'),
|
||||
"content" varchar(2000) not null
|
||||
);
|
51
postgres/20-procedures.sql
Normal file
51
postgres/20-procedures.sql
Normal file
@ -0,0 +1,51 @@
|
||||
create or replace procedure add_user(
|
||||
in in_username varchar(32),
|
||||
in in_password_hash varchar(72)
|
||||
)
|
||||
language plpgsql
|
||||
as $$
|
||||
begin
|
||||
insert into "user" ("username", "password_hash")
|
||||
values (in_username, in_password_hash);
|
||||
|
||||
insert into "role_binding" ("user_id", "role_id")
|
||||
values (
|
||||
(
|
||||
select "id"
|
||||
from "user"
|
||||
where "username" = in_username
|
||||
),
|
||||
(
|
||||
select "id"
|
||||
from "role"
|
||||
where "name" = 'member'
|
||||
)
|
||||
);
|
||||
end;
|
||||
$$;
|
||||
|
||||
create or replace procedure add_channel(
|
||||
in channel_name varchar(32),
|
||||
in channel_desc varchar(200)
|
||||
)
|
||||
language plpgsql
|
||||
as $$
|
||||
declare
|
||||
channel_id integer;
|
||||
begin
|
||||
insert into "channel" ("name", "description")
|
||||
values (channel_name, channel_desc)
|
||||
returning "id" into channel_id;
|
||||
|
||||
insert into "right" ("role_id", "channel_id", "rights")
|
||||
values (
|
||||
(
|
||||
select "id"
|
||||
from "role"
|
||||
where "name" = 'admin'
|
||||
),
|
||||
channel_id,
|
||||
'A'
|
||||
);
|
||||
end;
|
||||
$$
|
10
postgres/30-triggers.sql
Normal file
10
postgres/30-triggers.sql
Normal file
@ -0,0 +1,10 @@
|
||||
-- prevent deleting or changing default roles
|
||||
create rule protect_special_roles_update as
|
||||
on update to "role"
|
||||
where old."name" = 'admin' or old."name" = 'member'
|
||||
do instead nothing;
|
||||
|
||||
create rule protect_special_roles_delete as
|
||||
on delete to "role"
|
||||
where old."name" = 'admin' or old."name" = 'member'
|
||||
do instead nothing;
|
45
postgres/40-default.sql
Normal file
45
postgres/40-default.sql
Normal file
@ -0,0 +1,45 @@
|
||||
-- admin account and its role and right
|
||||
insert into "user" ("username", "password_hash")
|
||||
values (
|
||||
'admin',
|
||||
'$2a$12$FChbwNEIH9imtkTAkNq35eqMb.1C.1BP3bbuFZwOr7rOrs5luwCzq'
|
||||
);
|
||||
|
||||
insert into "role" ("name")
|
||||
values ('admin');
|
||||
|
||||
insert into "role_binding" ("user_id", "role_id")
|
||||
values (
|
||||
(
|
||||
select "id"
|
||||
from "user"
|
||||
where "username" = 'admin'
|
||||
),
|
||||
(
|
||||
select "id"
|
||||
from "role"
|
||||
where "name" = 'admin'
|
||||
)
|
||||
);
|
||||
|
||||
-- default channel
|
||||
call add_channel('default', 'default channel');
|
||||
|
||||
-- member role
|
||||
insert into "role" ("name")
|
||||
values ('member');
|
||||
|
||||
insert into "right" ("role_id", "channel_id", "rights")
|
||||
values (
|
||||
(
|
||||
select "id"
|
||||
from "role"
|
||||
where "name" = 'member'
|
||||
),
|
||||
(
|
||||
select "id"
|
||||
from "channel"
|
||||
where "name" = 'default'
|
||||
),
|
||||
'RW'
|
||||
);
|
4
valkey/users.acl
Normal file
4
valkey/users.acl
Normal file
@ -0,0 +1,4 @@
|
||||
user default off
|
||||
|
||||
user admin on >admin allcommands allkeys
|
||||
user readonly on >readonly ~* +@read
|
4
valkey/valkey.conf
Normal file
4
valkey/valkey.conf
Normal file
@ -0,0 +1,4 @@
|
||||
port 6379
|
||||
databases 1
|
||||
|
||||
aclfile /usr/local/etc/valkey/users.acl
|
Loading…
Reference in New Issue
Block a user