Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
15 changes: 15 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -100,6 +100,21 @@ cp .example.env .env
## Dev Services

## Database

### Database Views

The access policies and users documents are implemented as database views. To keep track of views and changes, make sure to use `yarn db:migrate-views` when changing views:

1. Edit or create a new view file in `prisma/view-migrations/views/`.
2. Make sure the dependencies are correct in [migrate.config.yml](prisma/view-migrations/migrate.config.yml).
3. Run `yarn db:migrate-views` to create a new migration for the changed views (this won't run `prisma migrate:dev`, it only creates the migration files).
4. Eventually change the [schema.prisma](prisma/schema.prisma) file to reflect changes in the views (e.g. new fields).
5. Run `yarn run prisma migrate:dev` to create a new migration for the schema changes.

> [!WARNING]
> Never edit views directly in a prisma migration file (under `prisma/migrations/`), as these files are auto-generated and will be overwritten the next time `yarn db:migrate-views` is run.


### Docker Compose

Run `scripts/purge_dev_services.sh` or the `purge_dev_services` run config to remove all containers **and volumes** associated with the dev services.
Expand Down
4 changes: 4 additions & 0 deletions package.json
Original file line number Diff line number Diff line change
Expand Up @@ -14,6 +14,7 @@
"format:check": "prettier --check ./**/*.{ts,json}",
"db:migrate": "yarn prisma migrate deploy",
"db:migrate:dev": "yarn prisma migrate dev",
"db:migrate-view": "ts-node -r dotenv/config ./prisma/view-migrations/create-view-migration.ts",
"db:seed": "yarn prisma db seed",
"db:reset": "dotenv -- ts-node prisma/reset.ts",
"db:recreate": "yarn run db:reset && yarn run db:migrate && yarn run db:seed",
Expand All @@ -40,6 +41,7 @@
"@mermaid-js/mermaid-cli": "^10.9.1",
"@types/cors": "^2.8.17",
"@types/express": "^5.0.3",
"@types/js-yaml": "^4.0.9",
"@types/morgan": "^1.9.9",
"@types/node": "^20.14.6",
"@typescript-eslint/eslint-plugin": "^8.44.1",
Expand All @@ -48,6 +50,8 @@
"eslint": "^9.36.0",
"eslint-config-prettier": "^10.1.8",
"eslint-plugin-prettier": "^5.5.4",
"js-yaml": "^4.1.1",
"minimist": "^1.2.8",
"nodemon": "^3.1.10",
"prettier": "^3.6.2",
"prisma": "^6.17.1",
Expand Down
105 changes: 105 additions & 0 deletions prisma/view-migrations/create-view-migration.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,105 @@
import * as fs from 'fs';
import * as path from 'path';
import * as yaml from 'js-yaml';
import { default as parseArgs } from 'minimist';
import { exit } from 'process';

const currentDir = __dirname;
const CONFIG_FILENAME = 'migrate.config.yml' as const;
interface Config {
name: string;
depends_on: string[];
}
const config = yaml.load(fs.readFileSync(path.resolve(currentDir, CONFIG_FILENAME), 'utf8')) as Config[];
const HELP_TEXT = `
yarn run db:migrate-view [view-name [view-name ...]]

Example:
yarn run db:migrate-view view__users_documents view__document_user_permissions

available views (configured in ${CONFIG_FILENAME}):
${config.map((c) => ` - ${c.name}`).join('\n')}
`;

const argv = parseArgs(process.argv.slice(2));

if (argv.help) {
console.log(HELP_TEXT);
exit(0);
}

const viewNames = argv._.filter(Boolean);
if (viewNames.length === 0) {
console.error('Error: No view name provided.');
console.log(HELP_TEXT);
exit(1);
}
if (viewNames.some((viewName) => !config.find((c) => c.name === viewName))) {
console.error(
'Error: Invalid view name provided. Unknown views:\n',
viewNames
.filter((viewName) => !config.find((c) => c.name === viewName))
.map((n) => `- ${n}`)
.join(`\n`),
`\nCheck ${CONFIG_FILENAME} to configure additional views.`
);
console.log(HELP_TEXT);
exit(1);
}

async function createViewMigration(viewNames: string[]) {
const migrationsFor: string[] = [];
const gatherDependencies = (viewName: string) => {
const viewConfig = config.find((c) => c.name === viewName);
if (!viewConfig) {
throw new Error(`View configuration for "${viewName}" not found.`);
}
const idx = migrationsFor.findIndex((name) => name === viewName);
if (idx >= 0) {
return;
}
const dependents = config.filter((dep) => dep.depends_on.includes(viewName)).map((d) => d.name);
for (const dep of dependents) {
gatherDependencies(dep);
}
if (!migrationsFor.includes(viewName)) {
migrationsFor.push(viewName);
}
};
viewNames.forEach(gatherDependencies);
console.log(migrationsFor.join(' -> '));

const commands: string[] = [];
commands.push(
`-- NEVER MODIFY THIS FILE MANUALLY! IT IS AUTO-GENERATED USING prisma/view-migrations/create-view-migration.ts`
);
migrationsFor.forEach((viewName) => {
commands.push(`DROP VIEW IF EXISTS ${viewName};`);
});
for (const viewName of migrationsFor.toReversed()) {
const viewSqlPath = path.resolve(currentDir, 'views', `${viewName}.sql`);
const viewSql = await fs.promises.readFile(viewSqlPath, 'utf8');
commands.push(`
CREATE VIEW ${viewName} AS
${viewSql
.replace(/;+\s*$/, '')
.trim()
.split('\n')
.map((line) => ` ${line}`)
.join('\n')};
`);
}
const migrationContent = commands.join('\n\n');
const timestamp = new Date()
.toISOString()
.replace(/[-:TZ.]/g, '')
.slice(0, 14);
const migrationFilename = `${timestamp}_create_views__${viewNames.map((name) => name.replace(/^view__/, '')).join('__')}`;
const migrationsDir = path.resolve(currentDir, '..', 'migrations', migrationFilename);
await fs.promises.mkdir(migrationsDir, { recursive: true });
const migrationFilePath = path.resolve(migrationsDir, 'migration.sql');
await fs.promises.writeFile(migrationFilePath, migrationContent, 'utf8');
console.log(`✅ Created view migration at: ${migrationFilePath}`);
}

createViewMigration(viewNames);
8 changes: 8 additions & 0 deletions prisma/view-migrations/migrate.config.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
- name: view__users_documents
depends_on:
- view__document_user_permissions
- name: view__document_user_permissions
depends_on:
- view__all_document_user_permissions
- name: view__all_document_user_permissions
depends_on: []
16 changes: 16 additions & 0 deletions prisma/view-migrations/tsconfig.json
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
{
"compilerOptions": {
"strict": true,
"lib": ["esnext", "dom"],
"target": "esnext",
"module": "commonjs",
"outDir": "../../dist/view-migrations",
"rootDir": "./",
"esModuleInterop": true,
"skipLibCheck": true,
"baseUrl": "../../",
"paths": {
"*": ["node_modules/*"]
}
}
}
122 changes: 122 additions & 0 deletions prisma/view-migrations/views/view__all_document_user_permissions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,122 @@
-- view: view__all_document_user_permissions

-- assumption: all child documents of a document share the same document_root_id
SELECT
document_root_id,
user_id,
access,
document_id,
root_user_permission_id,
root_group_permission_id,
group_id,
ROW_NUMBER() OVER (PARTITION BY document_root_id, user_id, document_id ORDER BY access DESC) AS access_rank
FROM (
-- get all documents where the user **is the author**
SELECT
document_roots.id AS document_root_id,
documents.author_id AS user_id,
document_roots.access AS access,
documents.id AS document_id,
NULL::uuid AS root_user_permission_id,
NULL::uuid AS root_group_permission_id,
NULL::uuid AS group_id
FROM
document_roots
INNER JOIN documents ON document_roots.id = documents.document_root_id
UNION ALL
-- get all documents where the user **is not the author** but has shared access
SELECT
document_roots.id AS document_root_id,
all_users.id AS user_id,
CASE
WHEN document_roots.shared_access <= document_roots.access THEN document_roots.shared_access
ELSE document_roots.access
END AS access,
documents.id AS document_id,
NULL::uuid AS root_user_permission_id,
NULL::uuid AS root_group_permission_id,
NULL::uuid AS group_id
FROM
document_roots
INNER JOIN documents ON document_roots.id = documents.document_root_id
CROSS JOIN users all_users
WHERE documents.author_id != all_users.id
AND (
document_roots.shared_access='RO_DocumentRoot'
OR
document_roots.shared_access='RW_DocumentRoot'
)
UNION ALL
-- get all documents where the user has been granted shared access
-- or the access has been extended by user permissions
SELECT
document_roots.id AS document_root_id,
rup.user_id AS user_id,
rup.access AS access,
documents.id AS document_id,
rup.id AS root_user_permission_id,
NULL::uuid AS root_group_permission_id,
NULL::uuid AS group_id
FROM
document_roots
LEFT JOIN documents ON document_roots.id=documents.document_root_id
LEFT JOIN root_user_permissions rup
ON (
document_roots.id = rup.document_root_id
AND (
documents.author_id = rup.user_id
OR
rup.access >= document_roots.shared_access
)
)
WHERE rup.user_id IS NOT NULL
UNION ALL
-- all group-based permissions for the documents author
SELECT
document_roots.id AS document_root_id,
user_to_sg.user_id AS user_id,
rgp.access AS access,
documents.id AS document_id,
NULL::uuid AS root_user_permission_id,
rgp.id AS root_group_permission_id,
sg.id AS group_id
FROM
document_roots
INNER JOIN root_group_permissions rgp ON document_roots.id=rgp.document_root_id
INNER JOIN student_groups sg ON rgp.student_group_id=sg.id
LEFT JOIN documents ON document_roots.id=documents.document_root_id
LEFT JOIN user_student_groups user_to_sg
ON (
user_to_sg.student_group_id=sg.id
AND (
user_to_sg.user_id=documents.author_id
OR documents.author_id is null
)
)
WHERE user_to_sg.user_id IS NOT NULL
UNION ALL
-- all group based permissions for the user, which is not the author
SELECT
document_roots.id AS document_root_id,
user_to_sg.user_id AS user_id,
rgp.access AS access,
documents.id AS document_id,
NULL::uuid AS root_user_permission_id,
rgp.id AS root_group_permission_id,
sg.id AS group_id
FROM
document_roots
INNER JOIN root_group_permissions rgp
ON (
document_roots.id=rgp.document_root_id
AND rgp.access >= document_roots.shared_access
)
INNER JOIN student_groups sg ON rgp.student_group_id=sg.id
LEFT JOIN documents ON document_roots.id=documents.document_root_id
LEFT JOIN user_student_groups user_to_sg
ON (
user_to_sg.student_group_id=sg.id
AND user_to_sg.user_id!=documents.author_id
)
WHERE user_to_sg.user_id IS NOT NULL
) as doc_user_permissions
12 changes: 12 additions & 0 deletions prisma/view-migrations/views/view__document_user_permissions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
-- view: view__document_user_permissions

SELECT
document_root_id,
user_id,
access,
document_id,
root_user_permission_id,
root_group_permission_id,
group_id
FROM view__all_document_user_permissions
WHERE access_rank = 1
46 changes: 46 additions & 0 deletions prisma/view-migrations/views/view__users_documents.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,46 @@
-- view: view__users_documents

SELECT
view__document_user_permissions.user_id AS user_id,
document_roots.*,
COALESCE(
JSONB_AGG(
DISTINCT JSONB_BUILD_OBJECT(
'id', view__document_user_permissions.root_group_permission_id,
'access', view__document_user_permissions.access,
'groupId', view__document_user_permissions.group_id
)
) FILTER (WHERE view__document_user_permissions.root_group_permission_id IS NOT NULL),
'[]'::jsonb
) AS "groupPermissions",
COALESCE(
JSONB_AGG(
DISTINCT JSONB_BUILD_OBJECT(
'id', view__document_user_permissions.root_user_permission_id,
'access', view__document_user_permissions.access,
'userId', view__document_user_permissions.user_id
)
) FILTER (WHERE view__document_user_permissions.root_user_permission_id IS NOT NULL),
'[]'::jsonb
) AS "userPermissions",
COALESCE(
JSONB_AGG(
JSONB_BUILD_OBJECT(
'id', d.id,
'authorId', d.author_id,
'type', d.type,
'data', CASE WHEN (view__document_user_permissions.access='None_DocumentRoot' OR view__document_user_permissions.access='None_StudentGroup' OR view__document_user_permissions.access='None_User') THEN NULL ELSE d.data END,
'parentId', d.parent_id,
'documentRootId', d.document_root_id,
'createdAt', d.created_at,
'updatedAt', d.updated_at
)
) FILTER (WHERE d.id IS NOT NULL),
'[]'::jsonb
) AS documents
FROM
document_roots
LEFT JOIN view__document_user_permissions ON document_roots.id=view__document_user_permissions.document_root_id
LEFT JOIN documents d ON document_roots.id=d.document_root_id AND view__document_user_permissions.document_id=d.id
WHERE view__document_user_permissions.user_id IS NOT NULL
GROUP BY document_roots.id, view__document_user_permissions.user_id
Loading
Loading