Skip to content

Commit

Permalink
Hck 8696 fine tune the other sql queries that are executed by the syn…
Browse files Browse the repository at this point in the history
…apse plugin during the re process (#91)

* HCK-8696: optimized indexes query

* HCK-8696: optimized indexes and memory optimized tables queries

* HCK-8696: refactored projection approach

* HCK-8696: removed redundant property and join

* HCK-8696: improved names for tables selected by the user builder classes

* HCK-8696: replaced inheritance with composition

* HCK-8696: removed unrelevant data query

* HCK-8696: transformed redundant classes into functions

---------

Co-authored-by: Thomas Jakemeyn <thomas.jakemeyn@gmail.com>
  • Loading branch information
WilhelmWesser and thomas-jakemeyn authored Nov 21, 2024
1 parent 935df71 commit faedb33
Show file tree
Hide file tree
Showing 7 changed files with 160 additions and 71 deletions.
77 changes: 41 additions & 36 deletions reverse_engineering/databaseService/databaseService.js
Original file line number Diff line number Diff line change
Expand Up @@ -5,10 +5,13 @@ const { getObjectsFromDatabase, getNewConnectionClientByDb } = require('./helper
const getSampleDocSize = require('../helpers/getSampleDocSize');
const { logAuthTokenInfo } = require('../helpers/logInfo');
const { getConnection } = require('./helpers/connection');
const {
queryForRetrievingTheTablesSelectedByTheUser,
} = require('../queries/queryForRetrievingTheTablesSelectedByTheUser');
const { progress } = require('../helpers/logInfo');
const {
getPartitionsSubQueryForRetrievingTheTablesSelectedByTheUser,
} = require('../queries/selectedTablesSubQuery/partitionsSubQueryForRetrievingTheTablesSelectedByTheUser');
const {
getDatabaseIndexesSubQueryForRetrievingTheTablesSelectedByTheUser,
} = require('../queries/selectedTablesSubQuery/databaseIndexesSubQueryForRetrievingTheTablesSelectedByTheUser');

const QUERY_REQUEST_TIMEOUT = 60000;

Expand Down Expand Up @@ -280,39 +283,39 @@ const getViewDistributedColumns = async ({ connectionClient, dbName, viewName, t
}
};

const getDatabaseIndexes = async ({ connectionClient, dbName, logger }) => {
const currentDbConnectionClient = await getNewConnectionClientByDb(connectionClient, dbName);

const getDatabaseIndexes = async ({ connectionClient, tablesInfo, dbName, logger }) => {
logger.log('info', { message: `Get '${dbName}' database indexes.` }, 'Reverse Engineering');
const currentDbConnectionClient = await getNewConnectionClientByDb(connectionClient, dbName);

try {
return mapResponse(
await currentDbConnectionClient.query`
SELECT
TableName = t.name,
IndexName = ind.name,
ic.is_descending_key,
ic.is_included_column,
ic.column_store_order_ordinal,
COL_NAME(t.object_id, ic.column_id) as columnName,
S.name as schemaName,
p.data_compression_desc as dataCompression,
ind.*
FROM sys.indexes ind
LEFT JOIN sys.tables t
ON ind.object_id = t.object_id
INNER JOIN sys.index_columns ic
ON ind.object_id = ic.object_id AND ind.index_id = ic.index_id
INNER JOIN sys.partitions p
ON p.object_id = t.object_id AND ind.index_id = p.index_id
INNER JOIN sys.objects O ON O.object_id = t.object_id
INNER JOIN sys.schemas S ON S.schema_id = O.schema_id
WHERE
ind.is_primary_key = 0
AND ind.is_unique_constraint = 0
AND t.is_ms_shipped = 0
`,
);
const tablesSelectedByTheUser = getDatabaseIndexesSubQueryForRetrievingTheTablesSelectedByTheUser({
schemaToTablesMap: tablesInfo,
});
const queryRetrievingTheIndexes = `
WITH user_selected_tables AS (${tablesSelectedByTheUser.sql()})
SELECT
TableName = t.${tablesSelectedByTheUser.projection.tableName},
IndexName = ind.name,
ic.is_descending_key,
ic.is_included_column,
ic.column_store_order_ordinal,
COL_NAME(t.${tablesSelectedByTheUser.projection.tableId}, ic.column_id) as columnName,
S.name as schemaName,
ind.*
FROM sys.indexes ind
LEFT JOIN user_selected_tables t
ON ind.object_id = t.${tablesSelectedByTheUser.projection.tableId}
INNER JOIN sys.index_columns ic
ON ind.object_id = ic.object_id AND ind.index_id = ic.index_id
INNER JOIN sys.objects O ON O.object_id = t.${tablesSelectedByTheUser.projection.tableId}
INNER JOIN sys.schemas S ON S.schema_id = O.schema_id
WHERE
ind.is_primary_key = 0
AND ind.is_unique_constraint = 0
AND t.${tablesSelectedByTheUser.projection.isMsShipped} = 0
`;

return mapResponse(await currentDbConnectionClient.query(queryRetrievingTheIndexes));
} catch (error) {
logger.log(
'error',
Expand All @@ -332,12 +335,14 @@ const getDatabaseIndexes = async ({ connectionClient, dbName, logger }) => {
const getPartitions = async ({ connectionClient, tablesInfo, dbName, logger }) => {
logger.log('info', { message: `Get '${dbName}' database partitions.` }, 'Reverse Engineering');
const currentDbConnectionClient = await getNewConnectionClientByDb(connectionClient, dbName);
const tablesSelectedByTheUser = queryForRetrievingTheTablesSelectedByTheUser({ schemaToTablesMap: tablesInfo });

try {
const tablesSelectedByTheUser = getPartitionsSubQueryForRetrievingTheTablesSelectedByTheUser({
schemaToTablesMap: tablesInfo,
});
const queryForRetrievingThePartitions = `
WITH user_selected_tables AS (${tablesSelectedByTheUser.sql()})
SELECT
WITH user_selected_tables AS (${tablesSelectedByTheUser.sql()})
SELECT
tbl.${tablesSelectedByTheUser.projection.schemaName} AS schemaName,
tbl.${tablesSelectedByTheUser.projection.tableName} AS tableName,
prt.partition_number,
Expand Down

This file was deleted.

Original file line number Diff line number Diff line change
@@ -0,0 +1,61 @@
const { getProjectedPropertiesNames } = require('./getProjectedPropertiesNames');

/**
@typedef {{
* sql: () => string,
* projection: Record<string, string>
* }} Query
*/
class QueryForRetrievingTheTablesSelectedByTheUser {
#buildPredicateForTable({ schema, table }) {
return `(sch.name = '${schema}' AND tbl.name = '${table}')`;
}

#buildPredicateForTablesInSchema({ schema, tables }) {
return tables.map(table => this.#buildPredicateForTable({ schema, table })).join('OR');
}

#buildProjection({ columnToAliasMap }) {
return Object.entries(columnToAliasMap)
.map(([column, alias]) => `${column} AS ${alias}`)
.join(',');
}

#queryForRetrievingTheTablesSelectedByTheUser({ schemaToTablesMap, columnToAliasMap }) {
const projection = this.#buildProjection({
columnToAliasMap,
});
const predicate = Object.entries(schemaToTablesMap)
.map(([schema, tables]) => this.#buildPredicateForTablesInSchema({ schema, tables }))
.join('OR');
const whereClause = Object.entries(schemaToTablesMap).length > 0 ? `WHERE ${predicate}` : '';
return `
SELECT
${projection}
FROM sys.tables tbl
JOIN sys.schemas sch ON sch.schema_id = tbl.schema_id
${whereClause}
`;
}

/**
*
* @param {{columnToAliasMap: Record<string, string>, schemaToTablesMap: Record<string, string[]>}} param
* @returns {Query}
*/
getQuery({ columnToAliasMap, schemaToTablesMap }) {
const query = this.#queryForRetrievingTheTablesSelectedByTheUser({
schemaToTablesMap,
columnToAliasMap,
});

return {
projection: getProjectedPropertiesNames({ columnToAliasMap }),
sql: () => query,
};
}
}

module.exports = {
QueryForRetrievingTheTablesSelectedByTheUser,
};
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
const { QueryForRetrievingTheTablesSelectedByTheUser } = require('./QueryForRetrievingTheTablesSelectedByTheUser');
const { getProjectedPropertiesNames } = require('./getProjectedPropertiesNames');

/**
* @typedef {import("./QueryForRetrievingTheTablesSelectedByTheUser").Query} Query
* @param {{schemaToTablesMap: Record<string, string[]>}} param
* @returns {Query}
*/
const getDatabaseIndexesSubQueryForRetrievingTheTablesSelectedByTheUser = ({ schemaToTablesMap }) => {
const selectedTablesQuery = new QueryForRetrievingTheTablesSelectedByTheUser();
const columnToAliasMap = {
'tbl.object_id': 'tableId',
'tbl.name': 'tableName',
'tbl.is_ms_shipped': 'isMsShipped',
};

return selectedTablesQuery.getQuery({
schemaToTablesMap,
columnToAliasMap,
});
};

module.exports = {
getDatabaseIndexesSubQueryForRetrievingTheTablesSelectedByTheUser,
};
Original file line number Diff line number Diff line change
@@ -0,0 +1,6 @@
const getProjectedPropertiesNames = ({ columnToAliasMap }) =>
Object.fromEntries(Object.values(columnToAliasMap).map(projectedName => [projectedName, projectedName]));

module.exports = {
getProjectedPropertiesNames,
};
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
const { QueryForRetrievingTheTablesSelectedByTheUser } = require('./QueryForRetrievingTheTablesSelectedByTheUser');
const { getProjectedPropertiesNames } = require('./getProjectedPropertiesNames');

/**
* @typedef {import("./QueryForRetrievingTheTablesSelectedByTheUser").Query} Query
* @param {{schemaToTablesMap: Record<string, string[]>}} param
* @returns {Query}
*/
const getPartitionsSubQueryForRetrievingTheTablesSelectedByTheUser = ({ schemaToTablesMap }) => {
const selectedTablesQuery = new QueryForRetrievingTheTablesSelectedByTheUser();
const columnToAliasMap = {
'tbl.object_id': 'tableId',
'tbl.name': 'tableName',
'sch.name': 'schemaName',
};

return selectedTablesQuery.getQuery({
schemaToTablesMap,
columnToAliasMap,
});
};

module.exports = {
getPartitionsSubQueryForRetrievingTheTablesSelectedByTheUser,
};
Original file line number Diff line number Diff line change
Expand Up @@ -343,7 +343,7 @@ const getIndexing = (indexingInfo, order) => {
};

const getOrder = indexingInfo => {
return indexingInfo.filter(column => column.column_store_order_ordinal).map(column => column.COLUMN_NAME);
return indexingInfo.filter(column => column.column_store_order_ordinal).map(column => column.columnName);
};

const getTableRole = (distribution, indexing) => {
Expand All @@ -370,7 +370,7 @@ const reverseCollectionsToJSON = logger => async (dbConnectionClient, tablesInfo
const dbName = dbConnectionClient.config.database;
progress(logger, `RE data from database "${dbName}"`, dbName);
const [databaseIndexes, databaseUDT, dataBasePartitions] = await Promise.all([
getDatabaseIndexes({ connectionClient: dbConnectionClient, dbName, logger }),
getDatabaseIndexes({ connectionClient: dbConnectionClient, tablesInfo, dbName, logger }),
getDatabaseUserDefinedTypes({ connectionClient: dbConnectionClient, dbName, logger }),
getPartitions({ connectionClient: dbConnectionClient, tablesInfo, dbName, logger }),
]);
Expand Down

0 comments on commit faedb33

Please sign in to comment.