Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Feature/add postgres schema support #2540

Open
wants to merge 3 commits into
base: main
Choose a base branch
from
Open
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
3 changes: 3 additions & 0 deletions .env.example
Original file line number Diff line number Diff line change
Expand Up @@ -20,6 +20,9 @@ DB_PAGE_LIMIT=50
DB_ENCRYPTION_KEY=
# Uncomment below if you wish to run DB migrations manually.
#DB_MANUAL_MIGRATION=true
# Specify postgres schema to use. In production, you will need to create the schema first
# to use this option. Jackson will not create it for you.
POSTGRES_SCHEMA=

# Admin Portal settings
# SMTP details for Magic Links
Expand Down
3 changes: 3 additions & 0 deletions lib/env.ts
Original file line number Diff line number Diff line change
Expand Up @@ -50,6 +50,9 @@ const db: DatabaseOption = {
writeCapacityUnits: process.env.DB_DYNAMODB_RCUS ? Number(process.env.DB_DYNAMODB_WCUS) : undefined,
},
manualMigration: process.env.DB_MANUAL_MIGRATION === 'true',
postgres: {
schema: process.env.POSTGRES_SCHEMA,
},
};

/** Indicates if the Jackson instance is hosted (i.e. not self-hosted) */
Expand Down
34 changes: 19 additions & 15 deletions npm/migration/postgres/1640877103193-Initial.ts
Original file line number Diff line number Diff line change
@@ -1,26 +1,30 @@
import {MigrationInterface, QueryRunner} from "typeorm";

const schema = process.env.POSTGRES_SCHEMA || "public";
const jacksonStoreTableName = `${schema}.jackson_store`;
const jacksonIndexTableName = `${schema}.jackson_index`;
const jacksonTTLTableName = `${schema}.hackson_ttl`;

export class Initial1640877103193 implements MigrationInterface {
name = 'Initial1640877103193'

public async up(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(`CREATE TABLE "jackson_store" ("key" character varying(1500) NOT NULL, "value" text NOT NULL, "iv" character varying(64), "tag" character varying(64), CONSTRAINT "PK_87b6fc1475fbd1228d2f53c6f4a" PRIMARY KEY ("key"))`);
await queryRunner.query(`CREATE TABLE "jackson_index" ("id" SERIAL NOT NULL, "key" character varying(1500) NOT NULL, "storeKey" character varying(1500) NOT NULL, CONSTRAINT "PK_a95aa83f01e3c73e126856b7820" PRIMARY KEY ("id"))`);
await queryRunner.query(`CREATE INDEX "_jackson_index_key" ON "jackson_index" ("key") `);
await queryRunner.query(`CREATE INDEX "_jackson_index_key_store" ON "jackson_index" ("key", "storeKey") `);
await queryRunner.query(`CREATE TABLE "jackson_ttl" ("key" character varying(1500) NOT NULL, "expiresAt" bigint NOT NULL, CONSTRAINT "PK_7c9bcdfb4d82e873e19935ec806" PRIMARY KEY ("key"))`);
await queryRunner.query(`CREATE INDEX "_jackson_ttl_expires_at" ON "jackson_ttl" ("expiresAt") `);
await queryRunner.query(`ALTER TABLE "jackson_index" ADD CONSTRAINT "FK_937b040fb2592b4671cbde09e83" FOREIGN KEY ("storeKey") REFERENCES "jackson_store"("key") ON DELETE CASCADE ON UPDATE NO ACTION`);
await queryRunner.query(`CREATE TABLE ${jacksonStoreTableName} ("key" character varying(1500) NOT NULL, "value" text NOT NULL, "iv" character varying(64), "tag" character varying(64), CONSTRAINT "PK_87b6fc1475fbd1228d2f53c6f4a" PRIMARY KEY ("key"))`);
await queryRunner.query(`CREATE TABLE ${jacksonIndexTableName} ("id" SERIAL NOT NULL, "key" character varying(1500) NOT NULL, "storeKey" character varying(1500) NOT NULL, CONSTRAINT "PK_a95aa83f01e3c73e126856b7820" PRIMARY KEY ("id"))`);
await queryRunner.query(`CREATE INDEX "_jackson_index_key" ON ${jacksonIndexTableName} ("key") `);
await queryRunner.query(`CREATE INDEX "_jackson_index_key_store" ON ${jacksonIndexTableName} ("key", "storeKey") `);
await queryRunner.query(`CREATE TABLE ${jacksonTTLTableName} ("key" character varying(1500) NOT NULL, "expiresAt" bigint NOT NULL, CONSTRAINT "PK_7c9bcdfb4d82e873e19935ec806" PRIMARY KEY ("key"))`);
await queryRunner.query(`CREATE INDEX "_jackson_ttl_expires_at" ON ${jacksonTTLTableName} ("expiresAt") `);
await queryRunner.query(`ALTER TABLE ${jacksonIndexTableName} ADD CONSTRAINT "FK_937b040fb2592b4671cbde09e83" FOREIGN KEY ("storeKey") REFERENCES ${jacksonStoreTableName}("key") ON DELETE CASCADE ON UPDATE NO ACTION`);
}

public async down(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(`ALTER TABLE "jackson_index" DROP CONSTRAINT "FK_937b040fb2592b4671cbde09e83"`);
await queryRunner.query(`DROP INDEX "public"."_jackson_ttl_expires_at"`);
await queryRunner.query(`DROP TABLE "jackson_ttl"`);
await queryRunner.query(`DROP INDEX "public"."_jackson_index_key_store"`);
await queryRunner.query(`DROP INDEX "public"."_jackson_index_key"`);
await queryRunner.query(`DROP TABLE "jackson_index"`);
await queryRunner.query(`DROP TABLE "jackson_store"`);
await queryRunner.query(`ALTER TABLE ${jacksonIndexTableName} DROP CONSTRAINT "FK_937b040fb2592b4671cbde09e83"`);
await queryRunner.query(`DROP INDEX ${schema}."_jackson_ttl_expires_at"`);
await queryRunner.query(`DROP TABLE ${jacksonTTLTableName}`);
await queryRunner.query(`DROP INDEX ${schema}."_jackson_index_key_store"`);
await queryRunner.query(`DROP INDEX ${schema}."_jackson_index_key"`);
await queryRunner.query(`DROP TABLE ${jacksonIndexTableName}`);
await queryRunner.query(`DROP TABLE ${jacksonStoreTableName}`);
}

}
11 changes: 7 additions & 4 deletions npm/migration/postgres/1644332647279-createdAt.ts
Original file line number Diff line number Diff line change
@@ -1,16 +1,19 @@
import {MigrationInterface, QueryRunner} from "typeorm";

const schema = process.env.POSTGRES_SCHEMA || "public";
const jacksonStoreTableName = `${schema}.jackson_store`;

export class createdAt1644332647279 implements MigrationInterface {
name = 'createdAt1644332647279'

public async up(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(`ALTER TABLE "jackson_store" ADD "createdAt" TIMESTAMP NOT NULL DEFAULT now()`);
await queryRunner.query(`ALTER TABLE "jackson_store" ADD "modifiedAt" TIMESTAMP`);
await queryRunner.query(`ALTER TABLE ${jacksonStoreTableName} ADD "createdAt" TIMESTAMP NOT NULL DEFAULT now()`);
await queryRunner.query(`ALTER TABLE ${jacksonStoreTableName} ADD "modifiedAt" TIMESTAMP`);
}

public async down(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(`ALTER TABLE "jackson_store" DROP COLUMN "modifiedAt"`);
await queryRunner.query(`ALTER TABLE "jackson_store" DROP COLUMN "createdAt"`);
await queryRunner.query(`ALTER TABLE ${jacksonStoreTableName} DROP COLUMN "modifiedAt"`);
await queryRunner.query(`ALTER TABLE ${jacksonStoreTableName} DROP COLUMN "createdAt"`);
}

}
11 changes: 7 additions & 4 deletions npm/migration/postgres/1692767993709-pg_namespace.ts
Original file line number Diff line number Diff line change
@@ -1,16 +1,19 @@
import { MigrationInterface, QueryRunner } from "typeorm";

const schema = process.env.POSTGRES_SCHEMA || "public";
const jacksonStoreTableName = `${schema}.jackson_store`;

export class PgNamespace1692767993709 implements MigrationInterface {
name = 'PgNamespace1692767993709'

public async up(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(`ALTER TABLE "jackson_store" ADD "namespace" character varying(64)`);
await queryRunner.query(`CREATE INDEX "_jackson_store_namespace" ON "jackson_store" ("namespace") `);
await queryRunner.query(`ALTER TABLE ${jacksonStoreTableName} ADD "namespace" character varying(64)`);
await queryRunner.query(`CREATE INDEX "_jackson_store_namespace" ON ${jacksonStoreTableName} ("namespace") `);
}

public async down(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(`DROP INDEX "public"."_jackson_store_namespace"`);
await queryRunner.query(`ALTER TABLE "jackson_store" DROP COLUMN "namespace"`);
await queryRunner.query(`DROP INDEX ${schema}."_jackson_store_namespace"`);
await queryRunner.query(`ALTER TABLE ${jacksonStoreTableName} DROP COLUMN "namespace"`);
}

}
31 changes: 31 additions & 0 deletions npm/migration/postgres/1692817789888-namespace.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,31 @@
import { MigrationInterface, QueryRunner } from "typeorm"

// This file is same as npm/migration/sql/1692817789888-namespace.ts,
// but, with the added postgres schema name.

const schema = process.env.POSTGRES_SCHEMA || "public";
const jacksonStoreTableName = `${schema}.jackson_store`;

export class namespace1692817789888 implements MigrationInterface {
name = 'namespace1692817789888'

public async up(queryRunner: QueryRunner): Promise<void> {
const response = await queryRunner.query(`select jackson.key from ${jacksonStoreTableName} jackson`)
const searchTerm = ':';
for (const k in response) {
const key = response[k].key;
const tokens2 = key.split(searchTerm).slice(0, 2);
const value = tokens2.join(searchTerm);
queryRunner.query(`update ${jacksonStoreTableName} set namespace = '${value}' where ${jacksonStoreTableName}.key = '${key}'`)
}
}

public async down(queryRunner: QueryRunner): Promise<void> {
const response = await queryRunner.query(`select jackson.key from ${jacksonStoreTableName} jackson`)
for (const k in response) {
const key = response[k].key;
queryRunner.query(`update ${jacksonStoreTableName} set namespace = NULL where ${jacksonStoreTableName}.key = '${key}'`)
}
}

}
1 change: 1 addition & 0 deletions npm/src/db/constants.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
export const DEFAULT_POSTGRES_SCHEMA = 'public';
3 changes: 3 additions & 0 deletions npm/src/db/defaultDb.ts
Original file line number Diff line number Diff line change
@@ -1,4 +1,5 @@
import { JacksonOption } from '../typings';
import { DEFAULT_POSTGRES_SCHEMA } from './constants';

export default function defaultDb(opts: JacksonOption) {
opts.db = opts.db || {};
Expand All @@ -12,6 +13,8 @@ export default function defaultDb(opts: JacksonOption) {
opts.db.dynamodb.readCapacityUnits = opts.db.dynamodb.readCapacityUnits || 5;
opts.db.dynamodb.writeCapacityUnits = opts.db.dynamodb.writeCapacityUnits || 5;
opts.db.manualMigration = opts.db.manualMigration || false;
opts.db.postgres = opts.db.postgres || {};
opts.db.postgres.schema = opts.db.postgres.schema || DEFAULT_POSTGRES_SCHEMA;

return opts;
}
24 changes: 21 additions & 3 deletions npm/src/db/sql/sql.ts
Original file line number Diff line number Diff line change
Expand Up @@ -6,8 +6,9 @@ import { DatabaseDriver, DatabaseOption, Index, Encrypted, Records, SortOrder }
import { DataSource, DataSourceOptions, In, IsNull } from 'typeorm';
import * as dbutils from '../utils';
import * as mssql from './mssql';
import { DEFAULT_POSTGRES_SCHEMA } from '../constants';

class Sql implements DatabaseDriver {
export class Sql implements DatabaseDriver {
private options: DatabaseOption;
private dataSource!: DataSource;
private storeRepository;
Expand All @@ -26,6 +27,7 @@ class Sql implements DatabaseDriver {

async init({ JacksonStore, JacksonIndex, JacksonTTL }): Promise<Sql> {
const sqlType = this.options.engine === 'planetscale' ? 'mysql' : this.options.type!;
const postgresSchema = this.options.postgres?.schema || DEFAULT_POSTGRES_SCHEMA;
// Synchronize by default for non-planetscale engines only if migrations are not set to run
let synchronize = !this.options.manualMigration;
if (this.options.engine === 'planetscale') {
Expand Down Expand Up @@ -53,14 +55,30 @@ class Sql implements DatabaseDriver {
...baseOpts,
});
} else {
this.dataSource = new DataSource(<DataSourceOptions>{
const dataSourceOptions = {
url: this.options.url,
ssl: this.options.ssl,
...baseOpts,
});
};

if (sqlType === 'postgres') {
dataSourceOptions['synchronize'] = false;
dataSourceOptions['schema'] = postgresSchema;
}
this.dataSource = new DataSource(<DataSourceOptions>dataSourceOptions);
}

await this.dataSource.initialize();

if (sqlType === 'postgres' && synchronize) {
// We skip synchronization for postgres databases because TypeORM
// does not create schemas if they don't exist, we manually run
// synchronize here if it is set to true.
const queryRunner = this.dataSource.createQueryRunner();
await queryRunner.query(`CREATE SCHEMA IF NOT EXISTS ${postgresSchema}`);
this.dataSource.synchronize();
}

break;
} catch (err) {
console.error(`error connecting to engine: ${this.options.engine}, type: ${sqlType} db: ${err}`);
Expand Down
3 changes: 3 additions & 0 deletions npm/src/typings.ts
Original file line number Diff line number Diff line change
Expand Up @@ -418,6 +418,9 @@ export interface DatabaseOption {
writeCapacityUnits?: number;
};
manualMigration?: boolean;
postgres?: {
schema?: string;
};
}

export interface JacksonOption {
Expand Down
37 changes: 35 additions & 2 deletions npm/test/db/db.test.ts
Original file line number Diff line number Diff line change
Expand Up @@ -9,6 +9,7 @@ const dbObjs: { [key: string]: DatabaseDriver } = {};
const connectionStores: Storable[] = [];
const ttlStores: Storable[] = [];
const ttl = 2;
const non_default_schema = 'non_default';

const record1 = {
id: '1',
Expand Down Expand Up @@ -130,6 +131,12 @@ const dbs = [
...postgresDbConfig,
encryptionKey,
},
{
...postgresDbConfig,
postgres: {
schema: non_default_schema,
},
},
{
...mongoDbConfig,
},
Expand Down Expand Up @@ -188,7 +195,11 @@ tap.before(async () => {
for (const idx in dbs) {
const opts = dbs[idx];
const db = await DB.new(opts, true);
dbObjs[opts.engine! + (opts.type ? opts.type : '')] = db;
if (opts.type === 'postgres' && opts['schema'] === non_default_schema) {
dbObjs[opts['schema'] + opts.engine! + (opts.type ? opts.type : '')] = db;
Copy link
Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

We needed a different DB object for the non default schema, that is why this condition. Previously, the previous db would have been overwritten by the new one.

} else {
dbObjs[opts.engine! + (opts.type ? opts.type : '')] = db;
}

const randomSession = Date.now();
connectionStores.push(db.store('saml:config:' + randomSession + randomBytes(4).toString('hex')));
Expand All @@ -201,15 +212,32 @@ tap.teardown(async () => {
});

tap.test('dbs', async () => {
// We need this to ensure that the test runs atleast once.
// It is quite easy to skip the test by mistake in the future
// if one of the conditions change and it goes unnoticed.
let has_non_default_postgres_schema_test_ran = false;
for (const idx in connectionStores) {
const connectionStore = connectionStores[idx];
const ttlStore = ttlStores[idx];
const dbEngine = dbs[idx].engine!;
let dbType = dbEngine;
let dbType = dbEngine.toString();
if (dbs[idx].type) {
dbType += ': ' + dbs[idx].type;
}

tap.test('Test non default postgres schema', (t) => {
if (dbType === 'sql: postgres' && dbs[idx].postgres?.schema === non_default_schema) {
t.same(
connectionStore['db']['db']['dataSource']['createQueryBuilder']()['connection']['options'][
'schema'
Copy link
Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Not the cleanest solution, but since we want to expose a limited number of methods in DatabaseDriver, we needed to access private members of the class to test our changes

],
non_default_schema
);
}
has_non_default_postgres_schema_test_ran = true;
t.end();
});

tap.test('put(): ' + dbType, async () => {
await connectionStore.put(
record1.id,
Expand Down Expand Up @@ -527,4 +555,9 @@ tap.test('dbs', async () => {
await value.close();
}
});

tap.test('Ensure that the test for non default postgres schema has ran atleast once', (t) => {
t.same(has_non_default_postgres_schema_test_ran, true);
t.end();
});
});
11 changes: 8 additions & 3 deletions npm/typeorm.ts
Original file line number Diff line number Diff line change
@@ -1,6 +1,7 @@
require('reflect-metadata');
import { DataSource, DatabaseType, DataSourceOptions } from 'typeorm';
import * as mssql from './src/db/sql/mssql';
import { DEFAULT_POSTGRES_SCHEMA } from './src/db/constants';

const type =
process.env.DB_ENGINE === 'planetscale'
Expand Down Expand Up @@ -45,7 +46,7 @@ const baseOpts = {
logging: 'all',
entities: [`src/db/${entitiesDir}/entity/**/*.ts`],
migrations:
type === 'mssql'
type === 'mssql' || type === 'postgres'
? [`migration/${migrationsDir}/**/*.ts`]
: [`migration/${migrationsDir}/**/*.ts`, `migration/sql/**/*.ts`],
};
Expand All @@ -62,14 +63,18 @@ if (type === 'mssql') {
...baseOpts,
});
} else {
AppDataSource = new DataSource(<DataSourceOptions>{
const dataSourceOptions = {
url:
process.env.DB_URL ||
process.env.DATABASE_URL ||
'postgresql://postgres:postgres@localhost:5432/postgres',
ssl,
...baseOpts,
});
};
if (type === 'postgres') {
dataSourceOptions['schema'] = process.env.POSTGRES_SCHEMA || DEFAULT_POSTGRES_SCHEMA;
}
AppDataSource = new DataSource(<DataSourceOptions>dataSourceOptions);
}

export default AppDataSource;
Loading