diff --git a/adonis-typings/database.ts b/adonis-typings/database.ts index 0733ea6d..0fe5be67 100644 --- a/adonis-typings/database.ts +++ b/adonis-typings/database.ts @@ -44,15 +44,22 @@ declare module '@ioc:Adonis/Lucid/Database' { } /** - * Dialect specfic methods + * Dialect specific methods */ export interface DialectContract { readonly name: 'mssql' | 'mysql' | 'oracledb' | 'postgres' | 'redshift' | 'sqlite3' readonly version?: string readonly supportsAdvisoryLocks: boolean readonly dateTimeFormat: string + getAllTables(schemas?: string[]): Promise + getAllViews(schemas?: string[]): Promise + getAllTypes(schemas?: string[]): Promise + dropAllTables(schemas?: string[]): Promise + dropAllViews(schemas?: string[]): Promise + dropAllTypes(schemas?: string[]): Promise + truncate(table: string, cascade?: boolean): Promise getAdvisoryLock(key: string | number, timeout?: number): Promise releaseAdvisoryLock(key: string | number): Promise @@ -179,11 +186,31 @@ declare module '@ioc:Adonis/Lucid/Database' { */ getAllTables(schemas?: string[]): Promise + /** + * Returns an array of all views names for one or many schemas + */ + getAllViews(schemas?: string[]): Promise + + /** + * Returns an array of all types names + */ + getAllTypes(schemas?: string[]): Promise + /** * Drop all tables inside database */ dropAllTables(schemas?: string[]): Promise + /** + * Drop all views inside the database + */ + dropAllViews(schemas?: string[]): Promise + + /** + * Drop all types inside the database + */ + dropAllTypes(schemas?: string[]): Promise + /** * Same as `query()`, but also selects the table for the query. The `from` method * doesn't allow defining the return type and one must use `query` to define @@ -545,7 +572,7 @@ declare module '@ioc:Adonis/Lucid/Database' { /** * Add a new connection to the list of managed connection. You must call - * connect seperately to instantiate a connection instance + * connect separately to instantiate a connection instance */ add(connectionName: string, config: ConnectionConfig): void diff --git a/adonis-typings/model.ts b/adonis-typings/model.ts index 530473e6..829e9fa2 100644 --- a/adonis-typings/model.ts +++ b/adonis-typings/model.ts @@ -94,7 +94,7 @@ declare module '@ioc:Adonis/Lucid/Orm' { */ export type ExtractScopes = { [Scope in keyof PickProperties>]: ( - ...args: OmitFirst + ...args: any[] ) => ExtractScopes } diff --git a/commands/DbWipe.ts b/commands/DbWipe.ts index 77b5ca92..71039aff 100644 --- a/commands/DbWipe.ts +++ b/commands/DbWipe.ts @@ -2,7 +2,7 @@ import { BaseCommand, flags } from '@adonisjs/core/build/standalone' export default class DbWipe extends BaseCommand { public static commandName = 'db:wipe' - public static description = 'Drop all tables in database' + public static description = 'Drop all tables, views and types in database' /** * Choose a custom pre-defined connection. Otherwise, we use the @@ -11,6 +11,18 @@ export default class DbWipe extends BaseCommand { @flags.string({ description: 'Define a custom database connection', alias: 'c' }) public connection: string + /** + * Drop all views in database + */ + @flags.boolean({ description: 'Also drop all views in database' }) + public dropViews: boolean + + /** + * Drop all types in database + */ + @flags.boolean({ description: 'Also drop all types in database ( Postgres only )' }) + public dropTypes: boolean + /** * Force command execution in production */ @@ -48,8 +60,18 @@ export default class DbWipe extends BaseCommand { return } + if (this.dropViews) { + await db.connection().dropAllViews() + this.logger.info('All views dropped successfully') + } + await db.connection().dropAllTables() - this.logger.success('All tables have been dropped successfully') + this.logger.info('All tables have been dropped successfully') + + if (this.dropTypes) { + await db.connection().dropAllTypes() + this.logger.info('All types dropped successfully') + } } /** diff --git a/commands/Migration/Fresh.ts b/commands/Migration/Fresh.ts index 2ef02846..e1767c0f 100644 --- a/commands/Migration/Fresh.ts +++ b/commands/Migration/Fresh.ts @@ -36,6 +36,18 @@ export default class Refresh extends MigrationsBase { @flags.boolean({ description: 'Indicates if the seed task should run.' }) public seed: boolean + /** + * Drop all views in database + */ + @flags.boolean({ description: 'Also drop all views in database' }) + public dropViews: boolean + + /** + * Drop all types in database + */ + @flags.boolean({ description: 'Also drop all types in database ( Postgres only )' }) + public dropTypes: boolean + /** * This command loads the application, since we need the runtime * to find the migration directories for a given connection @@ -94,6 +106,8 @@ export default class Refresh extends MigrationsBase { const resetCmd = new DbWipe(this.application, this.kernel) resetCmd.connection = this.connection resetCmd.force = true + resetCmd.dropTypes = this.dropTypes + resetCmd.dropViews = this.dropViews await resetCmd.run() } diff --git a/package.json b/package.json index 6634562b..3a79da54 100644 --- a/package.json +++ b/package.json @@ -16,11 +16,11 @@ "scripts": { "mrm": "mrm --preset=@adonisjs/mrm-preset", "pretest": "npm run lint", - "test:sqlite": "DB=sqlite FORCE_COLOR=true node japaFile.js", - "test:mysql": "DB=mysql FORCE_COLOR=true node japaFile.js", - "test:mysql_legacy": "DB=mysql_legacy FORCE_COLOR=true node japaFile.js", - "test:mssql": "DB=mssql FORCE_COLOR=true node japaFile.js", - "test:pg": "DB=pg FORCE_COLOR=true node japaFile.js", + "test:sqlite": "cross-env DB=sqlite FORCE_COLOR=true node japaFile.js", + "test:mysql": "cross-env DB=mysql FORCE_COLOR=true node japaFile.js", + "test:mysql_legacy": "cross-env DB=mysql_legacy FORCE_COLOR=true node japaFile.js", + "test:mssql": "cross-env DB=mssql FORCE_COLOR=true node japaFile.js", + "test:pg": "cross-env DB=pg FORCE_COLOR=true node japaFile.js", "test:docker": "npm run test:sqlite && npm run test:mysql && npm run test:mysql_legacy && npm run test:pg && npm run test:mssql", "test": "docker-compose -f docker-compose.yml -f docker-compose-test.yml build && docker-compose -f docker-compose.yml -f docker-compose-test.yml run --rm test", "lint": "eslint . --ext=.ts", @@ -75,6 +75,7 @@ "@types/qs": "^6.9.7", "chance": "^1.1.8", "copyfiles": "^2.4.1", + "cross-env": "^7.0.3", "del-cli": "^4.0.1", "dotenv": "^10.0.0", "eslint": "^7.31.0", diff --git a/src/Dialects/Mssql.ts b/src/Dialects/Mssql.ts index 812148e9..3ef9ad8b 100644 --- a/src/Dialects/Mssql.ts +++ b/src/Dialects/Mssql.ts @@ -74,6 +74,30 @@ export class MssqlDialect implements DialectContract { await this.client.rawQuery(`EXEC sp_MSforeachtable 'DROP TABLE \\?';`) } + public async getAllViews(): Promise { + throw new Error( + '"getAllViews" method not implemented is not implemented for mssql. Create a PR to add the feature' + ) + } + + public async getAllTypes(): Promise { + throw new Error( + '"getAllTypes" method not implemented is not implemented for mssql. Create a PR to add the feature' + ) + } + + public async dropAllViews(): Promise { + throw new Error( + '"dropAllViews" method not implemented is not implemented for mssql. Create a PR to add the feature' + ) + } + + public async dropAllTypes(): Promise { + throw new Error( + '"dropAllTypes" method not implemented is not implemented for mssql. Create a PR to add the feature' + ) + } + public getAdvisoryLock(): Promise { throw new Error( 'Support for advisory locks is not implemented for mssql. Create a PR to add the feature' diff --git a/src/Dialects/Mysql.ts b/src/Dialects/Mysql.ts index c74b4269..9cd3d811 100644 --- a/src/Dialects/Mysql.ts +++ b/src/Dialects/Mysql.ts @@ -68,11 +68,39 @@ export class MysqlDialect implements DialectContract { return tables.map(({ table_name }) => table_name) } + /** + * Returns an array of all views names + */ + public async getAllViews(): Promise { + const tables = await this.client + .query() + .from('information_schema.tables') + .select('table_name as table_name') + .where('TABLE_TYPE', 'VIEW') + .where('table_schema', new RawBuilder('database()')) + .orderBy('table_name', 'asc') + + return tables.map(({ table_name }) => table_name) + } + + /** + * Returns an array of all types names + */ + public async getAllTypes(): Promise { + throw new Error("MySQL doesn't support types") + } + /** * Drop all tables inside the database */ public async dropAllTables() { - const tables = await this.getAllTables() + let tables = await this.getAllTables() + + /** + * Add backquote around table names to avoid syntax errors + * in case of a table name with a reserved keyword + */ + tables = tables.map((table) => '`' + table + '`') /** * Cascade and truncate @@ -81,7 +109,7 @@ export class MysqlDialect implements DialectContract { try { await trx.rawQuery('SET FOREIGN_KEY_CHECKS=0;') - await trx.rawQuery(`DROP table ${tables.join(',')};`) + await trx.rawQuery(`DROP TABLE ${tables.join(',')};`) await trx.rawQuery('SET FOREIGN_KEY_CHECKS=1;') await trx.commit() } catch (error) { @@ -90,6 +118,22 @@ export class MysqlDialect implements DialectContract { } } + /** + * Drop all views inside the database + */ + public async dropAllViews(): Promise { + const views = await this.getAllViews() + + return this.client.rawQuery(`DROP VIEW ${views.join(',')};`) + } + + /** + * Drop all custom types inside the database + */ + public async dropAllTypes(): Promise { + throw new Error("MySQL doesn't support types") + } + /** * Attempts to add advisory lock to the database and * returns it's status. diff --git a/src/Dialects/Oracle.ts b/src/Dialects/Oracle.ts index fabb3725..fbd5eba9 100644 --- a/src/Dialects/Oracle.ts +++ b/src/Dialects/Oracle.ts @@ -56,6 +56,30 @@ export class OracleDialect implements DialectContract { ) } + public async getAllViews(): Promise { + throw new Error( + '"getAllViews" method is not implemented for oracledb. Create a PR to add the feature.' + ) + } + + public async getAllTypes(): Promise { + throw new Error( + '"getAllTypes" method is not implemented for oracledb. Create a PR to add the feature.' + ) + } + + public async dropAllViews(): Promise { + throw new Error( + '"dropAllViews" method is not implemented for oracledb. Create a PR to add the feature.' + ) + } + + public async dropAllTypes(): Promise { + throw new Error( + '"dropAllTypes" method is not implemented for oracledb. Create a PR to add the feature.' + ) + } + public getAdvisoryLock(): Promise { throw new Error( 'Support for advisory locks is not implemented for oracledb. Create a PR to add the feature' diff --git a/src/Dialects/Pg.ts b/src/Dialects/Pg.ts index b50d2e02..a85f356e 100644 --- a/src/Dialects/Pg.ts +++ b/src/Dialects/Pg.ts @@ -43,6 +43,34 @@ export class PgDialect implements DialectContract { return tables.map(({ table_name }) => table_name) } + /** + * Returns an array of all views names for one or many schemas + */ + public async getAllViews(schemas: string[]) { + const views = await this.client + .query() + .from('pg_catalog.pg_views') + .select('viewname as view_name') + .whereIn('schemaname', schemas) + .orderBy('viewname', 'asc') + + return views.map(({ view_name }) => view_name) + } + + /** + * Returns an array of all types names + */ + public async getAllTypes(_schemas: string[]) { + const types = await this.client + .query() + .select('pg_type.typname') + .distinct() + .from('pg_type') + .innerJoin('pg_enum', 'pg_enum.enumtypid', 'pg_type.oid') + + return types.map(({ typname }) => typname) + } + /** * Truncate pg table with option to cascade and restart identity */ @@ -62,6 +90,26 @@ export class PgDialect implements DialectContract { await this.client.rawQuery(`DROP table ${tables.join(',')} CASCADE;`) } + /** + * Drop all views inside the database + */ + public async dropAllViews(schemas: string[]) { + const views = await this.getAllViews(schemas) + if (!views.length) return + + await this.client.rawQuery(`DROP view ${views.join(',')} CASCADE;`) + } + + /** + * Drop all types inside the database + */ + public async dropAllTypes(schemas: string[]) { + const types = await this.getAllTypes(schemas) + if (!types.length) return + + await this.client.rawQuery(`DROP type ${types.join(',')};`) + } + /** * Attempts to add advisory lock to the database and * returns it's status. diff --git a/src/Dialects/Redshift.ts b/src/Dialects/Redshift.ts index 76c0a602..52a55b71 100644 --- a/src/Dialects/Redshift.ts +++ b/src/Dialects/Redshift.ts @@ -45,6 +45,38 @@ export class RedshiftDialect implements DialectContract { return tables.map(({ table_name }) => table_name) } + /** + * Returns an array of all views names for one or many schemas + * + * NOTE: ASSUMING FEATURE PARITY WITH POSTGRESQL HERE (NOT TESTED) + */ + public async getAllViews(schemas: string[]) { + const views = await this.client + .query() + .from('pg_catalog.pg_views') + .select('viewname as view_name') + .whereIn('schemaname', schemas) + .orderBy('viewname', 'asc') + + return views.map(({ view_name }) => view_name) + } + + /** + * Returns an array of all types names + * + * NOTE: ASSUMING FEATURE PARITY WITH POSTGRESQL HERE (NOT TESTED) + */ + public async getAllTypes(_schemas: string[]) { + const types = await this.client + .query() + .select('pg_type.typname') + .distinct() + .from('pg_type') + .innerJoin('pg_enum', 'pg_enum.enumtypid', 'pg_type.oid') + + return types.map(({ typname }) => typname) + } + /** * Truncate redshift table with option to cascade and restart identity. * @@ -66,6 +98,30 @@ export class RedshiftDialect implements DialectContract { await this.client.rawQuery(`DROP table ${tables.join(',')} CASCADE;`) } + /** + * Drop all views inside the database + * + * NOTE: ASSUMING FEATURE PARITY WITH POSTGRESQL HERE (NOT TESTED) + */ + public async dropAllViews(schemas: string[]) { + const views = await this.getAllViews(schemas) + if (!views.length) return + + await this.client.rawQuery(`DROP view ${views.join(',')} CASCADE;`) + } + + /** + * Drop all types inside the database + * + * NOTE: ASSUMING FEATURE PARITY WITH POSTGRESQL HERE (NOT TESTED) + */ + public async dropAllTypes(schemas: string[]) { + const types = await this.getAllTypes(schemas) + if (!types.length) return + + await this.client.rawQuery(`DROP type ${types.join(',')};`) + } + /** * Redshift doesn't support advisory locks. Learn more: * https://tableplus.com/blog/2018/10/redshift-vs-postgres-database-comparison.html diff --git a/src/Dialects/Sqlite.ts b/src/Dialects/Sqlite.ts index efbd9a3b..6740051f 100644 --- a/src/Dialects/Sqlite.ts +++ b/src/Dialects/Sqlite.ts @@ -44,6 +44,28 @@ export class SqliteDialect implements DialectContract { return tables.map(({ table_name }) => table_name) } + /** + * Returns an array of all views names + */ + public async getAllViews(): Promise { + const tables = await this.client + .query() + .from('sqlite_master') + .select('name as table_name') + .where('type', 'view') + .whereNot('name', 'like', 'sqlite_%') + .orderBy('name', 'asc') + + return tables.map(({ table_name }) => table_name) + } + + /** + * Returns an array of all types names + */ + public async getAllTypes(): Promise { + throw new Error("Sqlite doesn't support types") + } + /** * Truncate SQLITE tables */ @@ -63,6 +85,23 @@ export class SqliteDialect implements DialectContract { await this.client.rawQuery('VACUUM;') } + /** + * Drop all views inside the database + */ + public async dropAllViews(): Promise { + await this.client.rawQuery('PRAGMA writable_schema = 1;') + await this.client.rawQuery(`delete from sqlite_schema where type = 'view';`) + await this.client.rawQuery('PRAGMA writable_schema = 0;') + await this.client.rawQuery('VACUUM;') + } + + /** + * Drop all custom types inside the database + */ + public async dropAllTypes(): Promise { + throw new Error("Sqlite doesn't support types") + } + /** * Attempts to add advisory lock to the database and * returns it's status. diff --git a/src/QueryClient/index.ts b/src/QueryClient/index.ts index 54ad3fd5..c307b792 100644 --- a/src/QueryClient/index.ts +++ b/src/QueryClient/index.ts @@ -126,6 +126,20 @@ export class QueryClient implements QueryClientContract { return this.dialect.getAllTables(schemas) } + /** + * Returns an array of all views names + */ + public async getAllViews(schemas?: string[]): Promise { + return this.dialect.getAllViews(schemas) + } + + /** + * Returns an array of all types names + */ + public async getAllTypes(schemas?: string[]): Promise { + return this.dialect.getAllTypes(schemas) + } + /** * Drop all tables inside database */ @@ -133,6 +147,20 @@ export class QueryClient implements QueryClientContract { return this.dialect.dropAllTables(schemas || ['public']) } + /** + * Drop all views inside the database + */ + public async dropAllViews(schemas?: string[]): Promise { + return this.dialect.dropAllViews(schemas || ['public']) + } + + /** + * Drop all custom types inside the database + */ + public async dropAllTypes(schemas?: string[]): Promise { + return this.dialect.dropAllTypes(schemas || ['public']) + } + /** * Returns an instance of a transaction. Each transaction will * query and hold a single connection for all queries. diff --git a/src/TransactionClient/index.ts b/src/TransactionClient/index.ts index 1c5f2ab6..5dc1c15c 100644 --- a/src/TransactionClient/index.ts +++ b/src/TransactionClient/index.ts @@ -104,6 +104,16 @@ export class TransactionClient extends EventEmitter implements TransactionClient await this.dialect.truncate(table, cascade) } + /** + * Get columns info inside a transaction. You won't need it here, however + * added for API compatibility with the [[QueryClient]] class + */ + public async columnsInfo(table: string, column?: string): Promise { + const query = this.knexClient.select(table) + const result = await (column ? query.columnInfo(column) : query.columnInfo()) + return result + } + /** * Returns an array of table names */ @@ -112,13 +122,17 @@ export class TransactionClient extends EventEmitter implements TransactionClient } /** - * Get columns info inside a transaction. You won't need it here, however - * added for API compatibility with the [[QueryClient]] class + * Returns an array of all views names */ - public async columnsInfo(table: string, column?: string): Promise { - const query = this.knexClient.select(table) - const result = await (column ? query.columnInfo(column) : query.columnInfo()) - return result + public async getAllViews(schemas?: string[]): Promise { + return this.dialect.getAllViews(schemas) + } + + /** + * Returns an array of all types names + */ + public async getAllTypes(schemas?: string[]): Promise { + return this.dialect.getAllTypes(schemas) } /** @@ -128,6 +142,20 @@ export class TransactionClient extends EventEmitter implements TransactionClient return this.dialect.dropAllTables(schemas || ['public']) } + /** + * Drop all views inside the database + */ + public async dropAllViews(schemas?: string[]): Promise { + return this.dialect.dropAllViews(schemas || ['public']) + } + + /** + * Drop all custom types inside the database + */ + public async dropAllTypes(schemas?: string[]): Promise { + return this.dialect.dropAllTypes(schemas || ['public']) + } + /** * Get a new query builder instance */ diff --git a/test/commands/migrate.spec.ts b/test/commands/migrate.spec.ts index 6b663bfd..d49d99cf 100644 --- a/test/commands/migrate.spec.ts +++ b/test/commands/migrate.spec.ts @@ -69,7 +69,7 @@ test.group('Migrate', (group) => { assert.lengthOf(migrated, 1) assert.isTrue(hasUsersTable) - assert.equal(migrated[0].name.replaceAll('\\', '/'), 'database/migrations/users') + assert.equal(migrated[0].name, 'database/migrations/users') assert.equal(migrated[0].batch, 1) }) diff --git a/test/commands/wipe-fresh.spec.ts b/test/commands/wipe-fresh.spec.ts index 9cdca776..0fe2f57c 100644 --- a/test/commands/wipe-fresh.spec.ts +++ b/test/commands/wipe-fresh.spec.ts @@ -88,7 +88,7 @@ test.group('db:wipe and migrate:fresh', (group) => { assert.lengthOf(migrated, 1) assert.isTrue(hasUsersTable) - assert.equal(migrated[0].name.replaceAll('\\', '/'), 'database/migrations/users') + assert.equal(migrated[0].name, 'database/migrations/users') assert.equal(migrated[0].batch, 1) }) diff --git a/test/database/views-types.spec.ts b/test/database/views-types.spec.ts new file mode 100644 index 00000000..6bbb6303 --- /dev/null +++ b/test/database/views-types.spec.ts @@ -0,0 +1,103 @@ +/// + +import test from 'japa' +import { join } from 'path' +import { ApplicationContract } from '@ioc:Adonis/Core/Application' + +import { Connection } from '../../src/Connection' +import { QueryClient } from '../../src/QueryClient' +import { fs, getConfig, setup, cleanup, setupApplication } from '../../test-helpers' + +let app: ApplicationContract + +test.group('Query client | Views and types', (group) => { + group.before(async () => { + app = await setupApplication() + await setup() + }) + + group.after(async () => { + await cleanup(['temp_posts', 'temp_users']) + await cleanup() + await fs.cleanup() + }) + + if (['sqlite', 'mysql', 'pg'].includes(process.env.DB!)) { + test('Get all views', async (assert) => { + await fs.fsExtra.ensureDir(join(fs.basePath, 'temp')) + const connection = new Connection('primary', getConfig(), app.logger) + connection.connect() + const client = new QueryClient('dual', connection, app.container.use('Adonis/Core/Event')) + + await connection.client!.schema.createView('users_view', async (view) => { + view.columns(['username', 'email']) + view.as(connection.client!('users').select('username', 'email')) + }) + + await connection.client!.schema.createView('follows_view', async (view) => { + view.columns(['user_id']) + view.as(connection.client!('follows').select('user_id')) + }) + + const allViews = await client.getAllViews(['public']) + assert.deepEqual(allViews.sort(), ['users_view', 'follows_view'].sort()) + + await client.dropAllViews() + }) + + test('Drop all views', async (assert) => { + await fs.fsExtra.ensureDir(join(fs.basePath, 'temp')) + const connection = new Connection('primary', getConfig(), app.logger) + connection.connect() + const client = new QueryClient('dual', connection, app.container.use('Adonis/Core/Event')) + + await connection.client!.schema.createView('users_view', async (view) => { + view.columns(['username', 'email']) + view.as(connection.client!('users').select('username', 'email')) + }) + + await connection.client!.schema.createView('follows_view', async (view) => { + view.columns(['user_id']) + view.as(connection.client!('follows').select('user_id')) + }) + + let allViews = await client.getAllViews(['public']) + assert.deepEqual(allViews.sort(), ['users_view', 'follows_view'].sort()) + + await client.dropAllViews() + + allViews = await client.getAllViews(['public']) + assert.equal(allViews.length, 0) + }) + } + + if (['pg'].includes(process.env.DB!)) { + test('Get all types', async (assert) => { + await fs.fsExtra.ensureDir(join(fs.basePath, 'temp')) + const connection = new Connection('primary', getConfig(), app.logger) + connection.connect() + const client = new QueryClient('dual', connection, app.container.use('Adonis/Core/Event')) + + await client.rawQuery(`CREATE TYPE "user_type" AS ENUM ('admin', 'user')`) + const types = await client.getAllTypes(['public']) + + assert.equal(types.length, 1) + assert.equal(types[0], 'user_type') + + await client.dropAllTypes() + }) + + test('Drop all types', async (assert) => { + await fs.fsExtra.ensureDir(join(fs.basePath, 'temp')) + const connection = new Connection('primary', getConfig(), app.logger) + connection.connect() + const client = new QueryClient('dual', connection, app.container.use('Adonis/Core/Event')) + + await client.rawQuery(`CREATE TYPE "user_type" AS ENUM ('admin', 'user')`) + await client.dropAllTypes() + const types = await client.getAllTypes() + + assert.equal(types.length, 0) + }) + } +})