ff-admin-server/src/helpers/dynamicQueryBuilder.ts

417 lines
13 KiB
TypeScript

import { Brackets, DataSource, NotBrackets, ObjectLiteral, SelectQueryBuilder, WhereExpressionBuilder } from "typeorm";
import { dataSource } from "../data-source";
import { ConditionStructure, DynamicQueryStructure, FieldType, QueryResult } from "../type/dynamicQueries";
import { TableMeta } from "../type/tableMeta";
export default abstract class DynamicQueryBuilder {
public static allowedTables: Array<string> = [
"award",
"communication",
"communicationType",
"executivePosition",
"membershipStatus",
"qualification",
"salutation",
"member",
"memberAwards",
"memberExecutivePositions",
"memberQualifications",
"membership",
"memberView",
"memberExecutivePositionsView",
"memberQualificationsView",
"membershipView",
];
public static getTableMeta(tableName: string): TableMeta {
let { name, columns, relations } = dataSource.getMetadata(tableName);
const uniqueColumns = columns.map((c) => ({ column: c.propertyName, type: c.type }));
return {
tableName: name,
columns: [
...uniqueColumns,
...relations
.filter((r) => !uniqueColumns.some((c) => r.propertyName == c.column))
.map((r) => ({
column: r.propertyName,
type: r.inverseEntityMetadata?.columns.find((col) => col.propertyName === r.inverseSidePropertyPath)?.type,
})),
],
relations: relations.map((r) => ({
column: r.propertyName,
relationType: r.relationType,
referencedTableName: r.inverseEntityMetadata?.tableName,
})),
};
}
public static getAllTableMeta(): Array<TableMeta> {
return this.allowedTables.map((table) => this.getTableMeta(table));
}
public static buildQuery({
queryObj,
offset = 0,
count = 25,
noLimit = false,
}: {
queryObj?: DynamicQueryStructure;
offset?: number;
count?: number;
noLimit?: boolean;
}): SelectQueryBuilder<ObjectLiteral> {
let affix = Math.random().toString(36).substring(2);
let query = dataSource.getRepository(queryObj.table).createQueryBuilder(`${queryObj.table}_${affix}`);
this.buildDynamicQuery(query, queryObj, affix);
if (!noLimit) {
query.offset(offset);
query.limit(count);
}
return query;
}
private static buildDynamicQuery(
query: SelectQueryBuilder<ObjectLiteral>,
queryObject: DynamicQueryStructure,
affix: string = "",
depth: number = 0
): void {
const alias = queryObject.table + "_" + affix;
let firstSelect = true;
let selects: Array<string> = [];
if (queryObject.select == "*") {
let meta = this.getTableMeta(queryObject.table);
let relCols = meta.relations.map((r) => r.column);
selects = meta.columns.map((c) => c.column).filter((c) => !relCols.includes(c));
} else {
selects = queryObject.select;
}
for (const select of selects) {
if (firstSelect && depth == 0) {
query.select(`${alias}.${select}`);
firstSelect = false;
} else {
query.addSelect(`${alias}.${select}`);
}
}
if (queryObject.where) {
this.applyWhere(query, queryObject.where, alias);
}
if (queryObject.join) {
for (const join of queryObject.join) {
let subaffix = Math.random().toString(36).substring(2);
query.leftJoin(`${alias}.${join.foreignColumn}`, join.table + "_" + subaffix);
this.buildDynamicQuery(query, join, subaffix, depth + 1);
}
}
if (queryObject.orderBy) {
queryObject.orderBy.forEach((order) => {
query.addOrderBy(`${alias}.${order.column}`, order.order);
});
}
}
public static applyWhere(
query: SelectQueryBuilder<ObjectLiteral> | WhereExpressionBuilder,
conditions: Array<ConditionStructure>,
alias: string
): void {
for (const condition of conditions) {
if (condition.structureType == "condition") {
const whereClause = this.buildConditionClause(condition, alias);
if (condition.concat == "_" || condition.concat == "AND") {
query.andWhere(whereClause.query, whereClause.parameters);
} else {
query.orWhere(whereClause.query, whereClause.parameters);
}
} else {
if (condition.concat == "_" || condition.concat == "AND") {
query.andWhere(
condition.invert == undefined || condition.invert == true
? new Brackets((qb) => {
this.applyWhere(qb, condition.conditions, alias);
})
: new NotBrackets((qb) => {
this.applyWhere(qb, condition.conditions, alias);
})
);
} else {
query.orWhere(
condition.invert == undefined || condition.invert == true
? new Brackets((qb) => {
this.applyWhere(qb, condition.conditions, alias);
})
: new NotBrackets((qb) => {
this.applyWhere(qb, condition.conditions, alias);
})
);
}
}
}
}
private static buildConditionClause(
condition: ConditionStructure & { structureType: "condition" },
alias: string
): { query: string; parameters: Record<string, unknown> } {
const parameterKey = `${alias}_${condition.column}_${Math.random().toString(36).substring(2)}`;
let query = `${alias}.${condition.column}`;
let parameters: Record<string, unknown> = {};
switch (condition.operation) {
case "eq":
query += ` = :${parameterKey}`;
parameters[parameterKey] = condition.value;
break;
case "neq":
query += ` != :${parameterKey}`;
parameters[parameterKey] = condition.value;
break;
case "lt":
query += ` < :${parameterKey}`;
parameters[parameterKey] = condition.value;
break;
case "lte":
query += ` <= :${parameterKey}`;
parameters[parameterKey] = condition.value;
break;
case "gt":
query += ` > :${parameterKey}`;
parameters[parameterKey] = condition.value;
break;
case "gte":
query += ` >= :${parameterKey}`;
parameters[parameterKey] = condition.value;
break;
case "in":
query += ` IN (:...${parameterKey})`;
parameters[parameterKey] = condition.value;
break;
case "notIn":
query += ` NOT IN (:...${parameterKey})`;
parameters[parameterKey] = condition.value;
break;
case "between":
query += ` BETWEEN :${parameterKey}_start AND :${parameterKey}_end`;
parameters[`${parameterKey}_start`] = (condition.value as { start: any }).start;
parameters[`${parameterKey}_end`] = (condition.value as { end: any }).end;
break;
case "null":
query += ` IS NULL`;
break;
case "notNull":
query += ` IS NOT NULL`;
break;
case "contains":
query += ` LIKE :${parameterKey}`;
parameters[parameterKey] = `%${condition.value}%`;
break;
case "notContains":
query += ` NOT LIKE :${parameterKey}`;
parameters[parameterKey] = `%${condition.value}%`;
break;
case "startsWith":
query += ` LIKE :${parameterKey}`;
parameters[parameterKey] = `${condition.value}%`;
break;
case "endsWith":
query += ` LIKE :${parameterKey}`;
parameters[parameterKey] = `%${condition.value}`;
break;
case "timespanEq":
query += ` BETWEEN :${parameterKey}_start AND :${parameterKey}_end`;
parameters[`${parameterKey}_start`] = new Date(new Date().getFullYear() - (condition.value as number), 0, 1);
parameters[`${parameterKey}_end`] = new Date(new Date().getFullYear() - (condition.value as number), 11, 31);
}
return { query, parameters };
}
public static flattenQueryResult(result: Array<QueryResult>): Array<{ [key: string]: FieldType }> {
function flatten(row: QueryResult, prefix: string = ""): Array<{ [key: string]: FieldType }> {
let results: Array<{ [key: string]: FieldType }> = [{}];
for (const key in row) {
const value = row[key];
const newKey = prefix ? `${prefix}_${key}` : key;
if (Array.isArray(value) && value.every((item) => typeof item === "object" && item !== null)) {
const arrayResults: Array<{ [key: string]: FieldType }> = [];
value.forEach((item) => {
const flattenedItems = flatten(item, newKey);
arrayResults.push(...flattenedItems);
});
const tempResults: Array<{ [key: string]: FieldType }> = [];
results.forEach((res) => {
arrayResults.forEach((arrRes) => {
tempResults.push({ ...res, ...arrRes });
});
});
results = tempResults;
} else if (value && typeof value === "object" && !Array.isArray(value) && !(value instanceof Date)) {
const objResults = flatten(value as QueryResult, newKey);
const tempResults: Array<{ [key: string]: FieldType }> = [];
results.forEach((res) => {
objResults.forEach((objRes) => {
tempResults.push({ ...res, ...objRes });
});
});
results = tempResults;
} else {
results.forEach((res) => {
if (String(value) != "undefined") res[newKey] = String(value);
});
}
}
return results;
}
const flattenedResults: Array<{ [key: string]: FieldType }> = [];
result.forEach((item) => {
const flattenedItems = flatten(item);
flattenedResults.push(...flattenedItems);
});
return flattenedResults;
}
public static async executeQuery({
query = "",
offset = 0,
count = 25,
noLimit = false,
}: {
query: string | DynamicQueryStructure;
offset?: number;
count?: number;
noLimit?: boolean;
}): Promise<
| {
stats: "error";
sql: string;
code: string;
msg: string;
}
| {
stats: "success";
rows: Array<{ [key: string]: FieldType }>;
total: number;
offset: number;
count: number;
}
> {
if (query == "member") {
query = memberQuery;
}
if (query == "memberByRunningMembership") {
query = memberByRunningMembershipQuery;
}
if (typeof query == "string") {
const upperQuery = query.trim().toUpperCase();
if (!upperQuery.startsWith("SELECT") || /INSERT|UPDATE|DELETE|ALTER|DROP|CREATE|TRUNCATE/.test(upperQuery)) {
return {
stats: "error",
sql: query,
code: "UNALLOWED",
msg: "Not allowed to change rows",
};
}
try {
let data: Array<any> = [];
return await dataSource
.transaction(async (manager) => {
data = await manager.query(query.toString());
throw new Error("AllwaysRollbackQuery");
})
.catch((error) => {
if (error.message === "AllwaysRollbackQuery") {
return {
stats: "success",
rows: data,
total: data.length,
offset: offset,
count: count,
};
} else {
return {
stats: "error",
sql: error.sql,
code: error.code,
msg: error.sqlMessage,
};
}
});
} catch (error) {
return {
stats: "error",
sql: error.sql,
code: error.code,
msg: error.sqlMessage,
};
}
} else {
try {
let [rows, total] = await this.buildQuery({ queryObj: query, offset, count, noLimit }).getManyAndCount();
return {
stats: "success",
rows: this.flattenQueryResult(rows),
total: total,
offset: offset,
count: noLimit ? total : count,
};
} catch (error) {
return {
stats: "error",
sql: error.sql,
code: error.code,
msg: error.sqlMessage,
};
}
}
}
}
const memberQuery: DynamicQueryStructure = {
select: "*",
table: "member",
orderBy: [
{ column: "lastname", order: "ASC" },
{ column: "firstname", order: "ASC" },
],
};
const memberByRunningMembershipQuery: DynamicQueryStructure = {
select: "*",
table: "member",
join: [
{
select: "*",
table: "membership",
where: [{ structureType: "condition", concat: "_", operation: "null", column: "end", value: "" }],
foreignColumn: "memberships",
},
],
orderBy: [
{ column: "lastname", order: "ASC" },
{ column: "firstname", order: "ASC" },
],
};