Skip to content

Commit

Permalink
fix: MATERIALIZED VIEW is treated as a regular VIEW which causes …
Browse files Browse the repository at this point in the history
…issues on sync (#7592)

* improved materialized view support in Postgres;

* improved materialized view support in Oracle;

* fixed falling test;
  • Loading branch information
AlexMesser committed Apr 26, 2021
1 parent 3f2a02c commit f85f436
Show file tree
Hide file tree
Showing 7 changed files with 212 additions and 26 deletions.
29 changes: 20 additions & 9 deletions src/driver/oracle/OracleQueryRunner.ts
Original file line number Diff line number Diff line change
Expand Up @@ -1153,10 +1153,17 @@ export class OracleQueryRunner extends BaseQueryRunner implements QueryRunner {
async clearDatabase(): Promise<void> {
await this.startTransaction();
try {
// drop views
const dropViewsQuery = `SELECT 'DROP VIEW "' || VIEW_NAME || '"' AS "query" FROM "USER_VIEWS"`;
const dropViewQueries: ObjectLiteral[] = await this.query(dropViewsQuery);
await Promise.all(dropViewQueries.map(query => this.query(query["query"])));

// drop materialized views
const dropMatViewsQuery = `SELECT 'DROP MATERIALIZED VIEW "' || MVIEW_NAME || '"' AS "query" FROM "USER_MVIEWS"`;
const dropMatViewQueries: ObjectLiteral[] = await this.query(dropMatViewsQuery);
await Promise.all(dropMatViewQueries.map(query => this.query(query["query"])));

// drop tables
const dropTablesQuery = `SELECT 'DROP TABLE "' || TABLE_NAME || '" CASCADE CONSTRAINTS' AS "query" FROM "USER_TABLES"`;
const dropTableQueries: ObjectLiteral[] = await this.query(dropTablesQuery);
await Promise.all(dropTableQueries.map(query => this.query(query["query"])));
Expand All @@ -1181,14 +1188,17 @@ export class OracleQueryRunner extends BaseQueryRunner implements QueryRunner {
return Promise.resolve([]);

const viewNamesString = viewNames.map(name => "'" + name + "'").join(", ");
let query = `SELECT "T".* FROM "${this.getTypeormMetadataTableName()}" "T" INNER JOIN "USER_VIEWS" "V" ON "V"."VIEW_NAME" = "T"."name" WHERE "T"."type" = 'VIEW'`;
let query = `SELECT "T".* FROM "${this.getTypeormMetadataTableName()}" "T" ` +
`INNER JOIN "USER_OBJECTS" "O" ON "O"."OBJECT_NAME" = "T"."name" AND "O"."OBJECT_TYPE" IN ( 'MATERIALIZED VIEW', 'VIEW' ) ` +
`WHERE "T"."type" IN ( 'MATERIALIZED_VIEW', 'VIEW' )`;
if (viewNamesString.length > 0)
query += ` AND "T"."name" IN (${viewNamesString})`;
const dbViews = await this.query(query);
return dbViews.map((dbView: any) => {
const view = new View();
view.name = dbView["name"];
view.expression = dbView["value"];
view.materialized = dbView["type"] === "MATERIALIZED_VIEW";
return view;
});
}
Expand Down Expand Up @@ -1444,10 +1454,11 @@ export class OracleQueryRunner extends BaseQueryRunner implements QueryRunner {

protected insertViewDefinitionSql(view: View): Query {
const expression = typeof view.expression === "string" ? view.expression.trim() : view.expression(this.connection).getQuery();
const type = view.materialized ? "MATERIALIZED_VIEW" : "VIEW"
const [query, parameters] = this.connection.createQueryBuilder()
.insert()
.into(this.getTypeormMetadataTableName())
.values({ type: "VIEW", name: view.name, value: expression })
.values({ type: type, name: view.name, value: expression })
.getQueryAndParameters();

return new Query(query, parameters);
Expand All @@ -1456,21 +1467,21 @@ export class OracleQueryRunner extends BaseQueryRunner implements QueryRunner {
/**
* Builds drop view sql.
*/
protected dropViewSql(viewOrPath: View|string): Query {
const viewName = viewOrPath instanceof View ? viewOrPath.name : viewOrPath;
return new Query(`DROP VIEW "${viewName}"`);
protected dropViewSql(view: View): Query {
const materializedClause = view.materialized ? "MATERIALIZED " : "";
return new Query(`DROP ${materializedClause}VIEW "${view.name}"`);
}

/**
* Builds remove view sql.
*/
protected deleteViewDefinitionSql(viewOrPath: View|string): Query {
const viewName = viewOrPath instanceof View ? viewOrPath.name : viewOrPath;
protected deleteViewDefinitionSql(view: View): Query {
const qb = this.connection.createQueryBuilder();
const type = view.materialized ? "MATERIALIZED_VIEW" : "VIEW"
const [query, parameters] = qb.delete()
.from(this.getTypeormMetadataTableName())
.where(`${qb.escape("type")} = 'VIEW'`)
.andWhere(`${qb.escape("name")} = :name`, { name: viewName })
.where(`${qb.escape("type")} = :type`, { type })
.andWhere(`${qb.escape("name")} = :name`, { name: view.name })
.getQueryAndParameters();

return new Query(query, parameters);
Expand Down
48 changes: 31 additions & 17 deletions src/driver/postgres/PostgresQueryRunner.ts
Original file line number Diff line number Diff line change
Expand Up @@ -326,7 +326,7 @@ export class PostgresQueryRunner extends BaseQueryRunner implements QueryRunner
async createDatabase(database: string, ifNotExist?: boolean): Promise<void> {
if (ifNotExist) {
const databaseAlreadyExists = await this.hasDatabase(database);

if (databaseAlreadyExists)
return Promise.resolve();
}
Expand Down Expand Up @@ -1401,16 +1401,27 @@ export class PostgresQueryRunner extends BaseQueryRunner implements QueryRunner

await this.startTransaction();
try {
// drop views
const selectViewDropsQuery = `SELECT 'DROP VIEW IF EXISTS "' || schemaname || '"."' || viewname || '" CASCADE;' as "query" ` +
`FROM "pg_views" WHERE "schemaname" IN (${schemaNamesString}) AND "viewname" NOT IN ('geography_columns', 'geometry_columns', 'raster_columns', 'raster_overviews')`;
const dropViewQueries: ObjectLiteral[] = await this.query(selectViewDropsQuery);
await Promise.all(dropViewQueries.map(q => this.query(q["query"])));

// drop materialized views
const selectMatViewDropsQuery = `SELECT 'DROP MATERIALIZED VIEW IF EXISTS "' || schemaname || '"."' || matviewname || '" CASCADE;' as "query" ` +
`FROM "pg_matviews" WHERE "schemaname" IN (${schemaNamesString})`;
const dropMatViewQueries: ObjectLiteral[] = await this.query(selectMatViewDropsQuery);
await Promise.all(dropMatViewQueries.map(q => this.query(q["query"])));

// ignore spatial_ref_sys; it's a special table supporting PostGIS
// TODO generalize this as this.driver.ignoreTables

// drop tables
const selectTableDropsQuery = `SELECT 'DROP TABLE IF EXISTS "' || schemaname || '"."' || tablename || '" CASCADE;' as "query" FROM "pg_tables" WHERE "schemaname" IN (${schemaNamesString}) AND "tablename" NOT IN ('spatial_ref_sys')`;
const dropTableQueries: ObjectLiteral[] = await this.query(selectTableDropsQuery);
await Promise.all(dropTableQueries.map(q => this.query(q["query"])));

// drop enum types
await this.dropEnumTypes(schemaNamesString);

await this.commitTransaction();
Expand Down Expand Up @@ -1442,14 +1453,18 @@ export class PostgresQueryRunner extends BaseQueryRunner implements QueryRunner
return `("t"."schema" = '${schema}' AND "t"."name" = '${name}')`;
}).join(" OR ");

const query = `SELECT "t".*, "v"."check_option" FROM ${this.escapePath(this.getTypeormMetadataTableName())} "t" ` +
`INNER JOIN "information_schema"."views" "v" ON "v"."table_schema" = "t"."schema" AND "v"."table_name" = "t"."name" WHERE "t"."type" = 'VIEW' ${viewsCondition ? `AND (${viewsCondition})` : ""}`;
const query = `SELECT "t".* FROM ${this.escapePath(this.getTypeormMetadataTableName())} "t" ` +
`INNER JOIN "pg_catalog"."pg_class" "c" ON "c"."relname" = "t"."name" ` +
`INNER JOIN "pg_namespace" "n" ON "n"."oid" = "c"."relnamespace" AND "n"."nspname" = "t"."schema" ` +
`WHERE "t"."type" IN ('VIEW', 'MATERIALIZED_VIEW') ${viewsCondition ? `AND (${viewsCondition})` : ""}`;

const dbViews = await this.query(query);
return dbViews.map((dbView: any) => {
const view = new View();
const schema = dbView["schema"] === currentSchema && !this.driver.options.schema ? undefined : dbView["schema"];
view.name = this.driver.buildTableName(dbView["name"], schema);
view.expression = dbView["value"];
view.materialized = dbView["type"] === "MATERIALIZED_VIEW";
return view;
});
}
Expand All @@ -1463,8 +1478,7 @@ export class PostgresQueryRunner extends BaseQueryRunner implements QueryRunner
if (!tableNames || !tableNames.length)
return [];

const currentSchemaQuery = await this.query(`SELECT * FROM current_schema()`);
const currentSchema: string = currentSchemaQuery[0]["current_schema"];
const currentSchema = await this.getCurrentSchema()

const tablesCondition = tableNames.map(tableName => {
let [schema, name] = tableName.split(".");
Expand Down Expand Up @@ -1918,8 +1932,7 @@ export class PostgresQueryRunner extends BaseQueryRunner implements QueryRunner
}

protected async insertViewDefinitionSql(view: View): Promise<Query> {
const currentSchemaQuery = await this.query(`SELECT * FROM current_schema()`);
const currentSchema = currentSchemaQuery[0]["current_schema"];
const currentSchema = await this.getCurrentSchema()
const splittedName = view.name.split(".");
let schema = this.driver.options.schema || currentSchema;
let name = view.name;
Expand All @@ -1928,11 +1941,12 @@ export class PostgresQueryRunner extends BaseQueryRunner implements QueryRunner
name = splittedName[1];
}

const type = view.materialized ? "MATERIALIZED_VIEW" : "VIEW"
const expression = typeof view.expression === "string" ? view.expression.trim() : view.expression(this.connection).getQuery();
const [query, parameters] = this.connection.createQueryBuilder()
.insert()
.into(this.getTypeormMetadataTableName())
.values({ type: "VIEW", schema: schema, name: name, value: expression })
.values({ type: type, schema: schema, name: name, value: expression })
.getQueryAndParameters();

return new Query(query, parameters);
Expand All @@ -1941,29 +1955,29 @@ export class PostgresQueryRunner extends BaseQueryRunner implements QueryRunner
/**
* Builds drop view sql.
*/
protected dropViewSql(viewOrPath: View|string): Query {
return new Query(`DROP VIEW ${this.escapePath(viewOrPath)}`);
protected dropViewSql(view: View): Query {
const materializedClause = view.materialized ? "MATERIALIZED " : "";
return new Query(`DROP ${materializedClause}VIEW ${this.escapePath(view)}`);
}

/**
* Builds remove view sql.
*/
protected async deleteViewDefinitionSql(viewOrPath: View|string): Promise<Query> {
const currentSchemaQuery = await this.query(`SELECT * FROM current_schema()`);
const currentSchema = currentSchemaQuery[0]["current_schema"];
const viewName = viewOrPath instanceof View ? viewOrPath.name : viewOrPath;
const splittedName = viewName.split(".");
protected async deleteViewDefinitionSql(view: View): Promise<Query> {
const currentSchema = await this.getCurrentSchema()
const splittedName = view.name.split(".");
let schema = this.driver.options.schema || currentSchema;
let name = viewName;
let name = view.name;
if (splittedName.length === 2) {
schema = splittedName[0];
name = splittedName[1];
}

const type = view.materialized ? "MATERIALIZED_VIEW" : "VIEW"
const qb = this.connection.createQueryBuilder();
const [query, parameters] = qb.delete()
.from(this.getTypeormMetadataTableName())
.where(`${qb.escape("type")} = 'VIEW'`)
.where(`${qb.escape("type")} = :type`, { type })
.andWhere(`${qb.escape("schema")} = :schema`, { schema })
.andWhere(`${qb.escape("name")} = :name`, { name })
.getQueryAndParameters();
Expand Down
61 changes: 61 additions & 0 deletions test/functional/query-runner/create-view.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,61 @@
import "reflect-metadata";
import { Connection } from "../../../src";
import { closeTestingConnections, createTestingConnections, reloadTestingDatabases } from "../../utils/test-utils";
import { View } from "../../../src/schema-builder/view/View";
import { expect } from "chai";

describe("query runner > create view", () => {

let connections: Connection[];
before(async () => {
connections = await createTestingConnections({
entities: [__dirname + "/view/*{.js,.ts}"],
enabledDrivers: ["postgres", "oracle"],
schemaCreate: true,
dropSchema: true,
});
});
beforeEach(() => reloadTestingDatabases(connections));
after(() => closeTestingConnections(connections));

it("should correctly create VIEW and revert creation", () => Promise.all(connections.map(async connection => {
const queryRunner = connection.createQueryRunner();
const view = new View({
name: "new_post_view",
expression: `SELECT * from "post"`
});
await queryRunner.createView(view);

let postView = await queryRunner.getView("new_post_view");
expect(postView).to.be.exist;

await queryRunner.executeMemoryDownSql();

postView = await queryRunner.getView("new_post_view");
expect(postView).to.be.not.exist;

await queryRunner.release();
})));

it("should correctly create MATERIALIZED VIEW and revert creation", () => Promise.all(connections.map(async connection => {
const queryRunner = connection.createQueryRunner();
const view = new View({
name: "new_post_materialized_view",
expression: `SELECT * from "post"`,
materialized: true
});
await queryRunner.createView(view);

let postMatView = await queryRunner.getView("new_post_materialized_view");
expect(postMatView).to.be.exist;
expect(postMatView!.materialized).to.be.true

await queryRunner.executeMemoryDownSql();

postMatView = await queryRunner.getView("new_post_materialized_view");
expect(postMatView).to.be.not.exist;

await queryRunner.release();
})));

});
54 changes: 54 additions & 0 deletions test/functional/query-runner/drop-view.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,54 @@
import "reflect-metadata";
import { Connection } from "../../../src";
import { closeTestingConnections, createTestingConnections, reloadTestingDatabases } from "../../utils/test-utils";
import { expect } from "chai";

describe("query runner > drop view", () => {

let connections: Connection[];
before(async () => {
connections = await createTestingConnections({
entities: [__dirname + "/view/*{.js,.ts}"],
enabledDrivers: ["postgres", "oracle"],
schemaCreate: true,
dropSchema: true,
});
});
beforeEach(() => reloadTestingDatabases(connections));
after(() => closeTestingConnections(connections));

it("should correctly drop VIEW and revert dropping", () => Promise.all(connections.map(async connection => {
const queryRunner = connection.createQueryRunner();

let postView = await queryRunner.getView("post_view");
await queryRunner.dropView(postView!);

postView = await queryRunner.getView("post_view");
expect(postView).to.be.not.exist;

await queryRunner.executeMemoryDownSql();

postView = await queryRunner.getView("post_view");
expect(postView).to.be.exist;

await queryRunner.release();
})));

it("should correctly drop MATERIALIZED VIEW and revert dropping", () => Promise.all(connections.map(async connection => {
const queryRunner = connection.createQueryRunner();

let postMatView = await queryRunner.getView("post_materialized_view");
await queryRunner.dropView(postMatView!);

postMatView = await queryRunner.getView("post_materialized_view");
expect(postMatView).to.be.not.exist;

await queryRunner.executeMemoryDownSql();

postMatView = await queryRunner.getView("post_materialized_view");
expect(postMatView).to.be.exist;

await queryRunner.release();
})));

});
21 changes: 21 additions & 0 deletions test/functional/query-runner/view/Post.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
import {Column, Entity, PrimaryColumn} from "../../../../src";

@Entity()
export class Post {

@PrimaryColumn()
id: number;

@Column({ unique: true })
version: number;

@Column({ default: "My post" })
name: string;

@Column()
text: string;

@Column()
tag: string;

}
13 changes: 13 additions & 0 deletions test/functional/query-runner/view/PostMaterializedView.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,13 @@
import {ViewColumn, ViewEntity} from "../../../../src";

@ViewEntity({
expression: `SELECT * FROM "post"`,
materialized: true,
})
export class PostMaterializedView {
@ViewColumn()
id: number

@ViewColumn()
type: string;
}
12 changes: 12 additions & 0 deletions test/functional/query-runner/view/PostView.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
import {ViewColumn, ViewEntity} from "../../../../src";

@ViewEntity({
expression: `SELECT * FROM "post"`
})
export class PostView {
@ViewColumn()
id: number

@ViewColumn()
type: string;
}

0 comments on commit f85f436

Please sign in to comment.