Skip to content

Commit 51a50fd

Browse files
committed
add: server
1 parent 0e2beec commit 51a50fd

Some content is hidden

Large Commits have some content hidden by default. Use the searchbox below for content that may be hidden.

43 files changed

+3948
-15
lines changed

.eslintrc.cjs

Lines changed: 23 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,3 +1,5 @@
1+
require('dotenv').config()
2+
13
/** @type {import("eslint").Linter.Config} */
24
module.exports = {
35
root: true,
@@ -70,6 +72,11 @@ module.exports = {
7072
project: "./tsconfig.json",
7173
},
7274
},
75+
{
76+
files: ["./server/**/*.ts"],
77+
parser: "@typescript-eslint/parser",
78+
plugins: ["@typescript-eslint", "@ts-safeql/eslint-plugin"],
79+
},
7380
],
7481
rules: {
7582
"no-undef": "off",
@@ -84,5 +91,21 @@ module.exports = {
8491
"react/react-in-jsx-scope": "off",
8592
"@typescript-eslint/no-unused-vars": "off", // typescript does this anyway
8693
"@typescript-eslint/no-explicit-any": "warn",
94+
"@ts-safeql/check-sql": [
95+
"error",
96+
{
97+
connections: [
98+
{
99+
databaseUrl: process.env.DATABASE_URL,
100+
targets: [
101+
{
102+
tag: "sql",
103+
transform: "{type}[]",
104+
},
105+
],
106+
},
107+
],
108+
},
109+
],
87110
},
88111
};

.gmrc

Lines changed: 119 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,119 @@
1+
/*
2+
* Graphile Migrate configuration.
3+
*
4+
* This file is version tracked, do not add any secrets (passwords, etc) to it
5+
* - manage these with environmental variables instead.
6+
*
7+
* This file is in JSON5 format, in VSCode you can use "JSON with comments" as
8+
* the file format.
9+
*/
10+
11+
{
12+
/*
13+
* Database connections strings are sourced from the DATABASE_URL,
14+
* SHADOW_DATABASE_URL and ROOT_DATABASE_URL environmental variables.
15+
*/
16+
17+
/*
18+
* pgSettings: key-value settings to be automatically loaded into PostgreSQL
19+
* before running migrations, using an equivalent of `SET LOCAL <key> TO
20+
* <value>`
21+
*/
22+
"pgSettings": {
23+
"search_path": "app_public,app_private,app_hidden,public"
24+
},
25+
26+
/*
27+
* placeholders: substituted in SQL files when compiled/executed. Placeholder
28+
* keys should be prefixed with a colon and in all caps, like
29+
* `:COLON_PREFIXED_ALL_CAPS`. Placeholder values should be strings. They
30+
* will be replaced verbatim with NO ESCAPING AT ALL (this differs from how
31+
* psql handles placeholders) so should only be used with "safe" values. This
32+
* is useful for committing migrations where certain parameters can change
33+
* between environments (development, staging, production) but you wish to
34+
* use the same signed migration files for all.
35+
*
36+
* The special value "!ENV" can be used to indicate an environmental variable
37+
* of the same name should be used.
38+
*
39+
* Graphile Migrate automatically sets the `:DATABASE_NAME` and
40+
* `:DATABASE_OWNER` placeholders, and you should not attempt to override
41+
* these.
42+
*/
43+
"placeholders": {
44+
":DATABASE_AUTHENTICATOR": "!ENV",
45+
":DATABASE_VISITOR": "!ENV"
46+
},
47+
48+
/*
49+
* Actions allow you to run scripts or commands at certain points in the
50+
* migration lifecycle. SQL files are ran against the database directly.
51+
* "command" actions are ran with the following environmental variables set:
52+
*
53+
* - GM_DBURL: the PostgreSQL URL of the database being migrated
54+
* - GM_DBNAME: the name of the database from GM_DBURL
55+
* - GM_DBUSER: the user from GM_DBURL
56+
* - GM_SHADOW: set to 1 if the shadow database is being migrated, left unset
57+
* otherwise
58+
*
59+
* If "shadow" is unspecified, the actions will run on events to both shadow
60+
* and normal databases. If "shadow" is true the action will only run on
61+
* actions to the shadow DB, and if false only on actions to the main DB.
62+
*/
63+
64+
/*
65+
* afterReset: actions executed after a `graphile-migrate reset` command.
66+
*/
67+
"afterReset": [
68+
"!afterReset.sql",
69+
],
70+
71+
/*
72+
* afterAllMigrations: actions executed once all migrations are complete.
73+
*/
74+
"afterAllMigrations": [
75+
// {
76+
// "_": "command",
77+
// "shadow": false,
78+
// "command": "node scripts/dump-db.js"
79+
// }
80+
],
81+
82+
/*
83+
* afterCurrent: actions executed once the current migration has been
84+
* evaluated (i.e. in watch mode).
85+
*/
86+
"afterCurrent": [
87+
// {
88+
// "_": "command",
89+
// "shadow": false,
90+
// "command": ""
91+
// }
92+
],
93+
94+
/*
95+
* blankMigrationContent: content to be written to the current migration
96+
* after commit. NOTE: this should only contain comments.
97+
*/
98+
// "blankMigrationContent": "",
99+
100+
/****************************************************************************\
101+
*** ***
102+
*** You probably don't want to edit anything below here. ***
103+
*** ***
104+
\****************************************************************************/
105+
106+
/*
107+
* manageGraphileMigrateSchema: if you set this false, you must be sure to
108+
* keep the graphile_migrate schema up to date yourself. We recommend you
109+
* leave it at its default.
110+
*/
111+
// "manageGraphileMigrateSchema": true,
112+
113+
/*
114+
* migrationsFolder: path to the folder in which to store your migrations.
115+
*/
116+
// migrationsFolder: "./migrations",
117+
118+
"//generatedWith": "0.1.0"
119+
}

docker-compose.yml

Lines changed: 21 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,21 @@
1+
services:
2+
db:
3+
image: postgres:16-alpine
4+
environment:
5+
- POSTGRES_USER=${ROOT_DATABASE_USER}
6+
- POSTGRES_PASSWORD=${ROOT_DATABASE_PASSWORD}
7+
command: postgres
8+
-c shared_preload_libraries=pg_stat_statements
9+
-c pg_stat_statements.track=all
10+
-c log_destination=stderr
11+
volumes:
12+
- /var/run/postgresql:/var/run/postgresql
13+
# - ./pgscripts:/docker-entrypoint-initdb.d
14+
# - ./data:/var/lib/postgresql/data
15+
networks:
16+
- appnet
17+
ports:
18+
- ${DATABASE_PORT}:5432
19+
20+
networks:
21+
appnet:

index.html

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -4,7 +4,7 @@
44
<meta charset="UTF-8" />
55
<link rel="icon" type="image/svg+xml" href="/vite.svg" />
66
<meta name="viewport" content="width=device-width, initial-scale=1.0" />
7-
<title>pg-fiddle</title>
7+
<title>postgres-playground</title>
88
</head>
99
<body class="h-full bg-primary-100 text-primary-900 dark:text-primary-100 dark:bg-primary-900 ">
1010
<div class="h-full" id="appRoot"></div>

migrations/afterReset.sql

Lines changed: 15 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,15 @@
1+
BEGIN;
2+
GRANT CONNECT ON DATABASE :DATABASE_NAME TO :DATABASE_OWNER;
3+
GRANT CONNECT ON DATABASE :DATABASE_NAME TO :DATABASE_AUTHENTICATOR;
4+
GRANT ALL ON DATABASE :DATABASE_NAME TO :DATABASE_OWNER;
5+
ALTER SCHEMA public OWNER TO :DATABASE_OWNER;
6+
7+
-- Some extensions require superuser privileges, so we create them before migration time.
8+
CREATE EXTENSION IF NOT EXISTS plpgsql WITH SCHEMA pg_catalog;
9+
CREATE EXTENSION IF NOT EXISTS "uuid-ossp" WITH SCHEMA public;
10+
CREATE EXTENSION IF NOT EXISTS citext WITH SCHEMA public;
11+
CREATE EXTENSION IF NOT EXISTS btree_gin WITH SCHEMA public;
12+
CREATE EXTENSION IF NOT EXISTS pgcrypto WITH SCHEMA public;
13+
CREATE EXTENSION IF NOT EXISTS pg_trgm WITH SCHEMA public;
14+
CREATE EXTENSION IF NOT EXISTS fuzzystrmatch WITH SCHEMA public;
15+
COMMIT;

migrations/current/0001-reset.sql

Lines changed: 10 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,10 @@
1+
/*
2+
* Graphile Migrate will run our `current/...` migrations in one batch. Since
3+
* this is our first migration it's defining the entire database, so we first
4+
* drop anything that may have previously been created
5+
* (app_public/app_hidden/app_private) so that we can start from scratch.
6+
*/
7+
8+
drop schema if exists app_public cascade;
9+
drop schema if exists app_hidden cascade;
10+
drop schema if exists app_private cascade;
Lines changed: 20 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,20 @@
1+
/*
2+
* The `public` *schema* contains things like PostgreSQL extensions. We
3+
* deliberately do not install application logic into the public schema
4+
* (instead storing it to app_public/app_hidden/app_private as appropriate),
5+
* but none the less we don't want untrusted roles to be able to install or
6+
* modify things into the public schema.
7+
*
8+
* The `public` *role* is automatically inherited by all other roles; we only
9+
* want specific roles to be able to access our database so we must revoke
10+
* access to the `public` role.
11+
*/
12+
13+
revoke all on schema public from public;
14+
15+
alter default privileges revoke all on sequences from public;
16+
alter default privileges revoke all on functions from public;
17+
18+
-- Of course we want our database owner to be able to do anything inside the
19+
-- database, so we grant access to the `public` schema:
20+
grant all on schema public to :DATABASE_OWNER;
Lines changed: 25 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,25 @@
1+
/*
2+
* Read about our app_public/app_hidden/app_private schemas here:
3+
* https://www.graphile.org/postgraphile/namespaces/#advice
4+
*
5+
* Note this pattern is not required to use PostGraphile, it's merely the
6+
* preference of the author of this package.
7+
*/
8+
9+
create schema app_public;
10+
create schema app_hidden;
11+
create schema app_private;
12+
13+
-- The 'visitor' role (used by PostGraphile to represent an end user) may
14+
-- access the public, app_public and app_hidden schemas (but _NOT_ the
15+
-- app_private schema).
16+
grant usage on schema public, app_public, app_hidden to :DATABASE_VISITOR;
17+
18+
-- We want the `visitor` role to be able to insert rows (`serial` data type
19+
-- creates sequences, so we need to grant access to that).
20+
alter default privileges in schema public, app_public, app_hidden
21+
grant usage, select on sequences to :DATABASE_VISITOR;
22+
23+
-- And the `visitor` role should be able to call functions too.
24+
alter default privileges in schema public, app_public, app_hidden
25+
grant execute on functions to :DATABASE_VISITOR;
Lines changed: 84 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,84 @@
1+
/*
2+
* These triggers are commonly used across many tables.
3+
*/
4+
5+
/*
6+
* This trigger is used on tables with created_at and updated_at to ensure that
7+
* these timestamps are kept valid (namely: `created_at` cannot be changed, and
8+
* `updated_at` must be monotonically increasing).
9+
*/
10+
create function app_private.tg__timestamps() returns trigger as $$
11+
begin
12+
NEW.created_at = (case when TG_OP = 'INSERT' then NOW() else OLD.created_at end);
13+
NEW.updated_at = (case when TG_OP = 'UPDATE' and OLD.updated_at >= NOW() then OLD.updated_at + interval '1 millisecond' else NOW() end);
14+
return NEW;
15+
end;
16+
$$ language plpgsql volatile set search_path to pg_catalog, public, pg_temp;
17+
18+
-- Used for queueing jobs easily; relies on the fact that every table we have
19+
-- has a primary key 'id' column; this won't work if you rename your primary
20+
-- key columns.
21+
create function app_private.tg__add_job() returns trigger as $$
22+
begin
23+
perform graphile_worker.add_job(tg_argv[0], json_build_object('id', NEW.id));
24+
return NEW;
25+
end;
26+
$$ language plpgsql volatile security definer set search_path to pg_catalog, public, pg_temp;
27+
28+
-- This trigger is used to queue a job to inform a user that a significant
29+
-- security change has been made to their account (e.g. adding a new email
30+
-- address, linking a new social login).
31+
create function app_private.tg__add_audit_job() returns trigger as $$
32+
declare
33+
v_user_id uuid;
34+
v_type text = TG_ARGV[0];
35+
v_user_id_attribute text = TG_ARGV[1];
36+
v_extra_attribute1 text = TG_ARGV[2];
37+
v_extra_attribute2 text = TG_ARGV[3];
38+
v_extra_attribute3 text = TG_ARGV[4];
39+
v_extra1 text;
40+
v_extra2 text;
41+
v_extra3 text;
42+
begin
43+
if v_user_id_attribute is null then
44+
raise exception 'Invalid tg__add_audit_job call';
45+
end if;
46+
47+
execute 'select ($1.' || quote_ident(v_user_id_attribute) || ')::uuid'
48+
using (case when TG_OP = 'INSERT' then NEW else OLD end)
49+
into v_user_id;
50+
51+
if v_extra_attribute1 is not null then
52+
execute 'select ($1.' || quote_ident(v_extra_attribute1) || ')::text'
53+
using (case when TG_OP = 'DELETE' then OLD else NEW end)
54+
into v_extra1;
55+
end if;
56+
if v_extra_attribute2 is not null then
57+
execute 'select ($1.' || quote_ident(v_extra_attribute2) || ')::text'
58+
using (case when TG_OP = 'DELETE' then OLD else NEW end)
59+
into v_extra2;
60+
end if;
61+
if v_extra_attribute3 is not null then
62+
execute 'select ($1.' || quote_ident(v_extra_attribute3) || ')::text'
63+
using (case when TG_OP = 'DELETE' then OLD else NEW end)
64+
into v_extra3;
65+
end if;
66+
67+
if v_user_id is not null then
68+
perform graphile_worker.add_job(
69+
'user__audit',
70+
json_build_object(
71+
'type', v_type,
72+
'user_id', v_user_id,
73+
'extra1', v_extra1,
74+
'extra2', v_extra2,
75+
'extra3', v_extra3,
76+
'current_user_id', app_public.current_user_id(),
77+
'schema', TG_TABLE_SCHEMA,
78+
'table', TG_TABLE_NAME
79+
));
80+
end if;
81+
82+
return NEW;
83+
end;
84+
$$ language plpgsql volatile security definer set search_path to pg_catalog, public, pg_temp;
Lines changed: 18 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,18 @@
1+
create table app_private.sessions (
2+
id text primary key,
3+
user_id uuid not null,
4+
expires_at timestamptz not null default now()
5+
);
6+
7+
create index sessions_user_id_idx on app_private.sessions (user_id);
8+
9+
alter table app_private.sessions enable row level security;
10+
11+
create function app_public.current_session_id() returns text as $$
12+
select nullif(pg_catalog.current_setting('jwt.claims.session_id', true), '');
13+
$$ language sql stable;
14+
15+
create function app_public.current_user_id() returns uuid as $$
16+
select user_id from app_private.sessions
17+
where id = app_public.current_session_id();
18+
$$ language sql stable security definer set search_path to pg_catalog, public, pg_temp;

0 commit comments

Comments
 (0)