From 683e31a7b5e2682981a60b3829fc42327b09c2ab Mon Sep 17 00:00:00 2001 From: jan Frode Haaskjold Date: Sun, 5 Jan 2025 11:07:46 +0100 Subject: [PATCH] feat: Right click option on SQL objects to view object locks --- global.d.ts | 1 + package.json | 10 + src/database/schemas.ts | 25 +- src/views/schemaBrowser/contributes.json | 10 + src/views/schemaBrowser/index.ts | 15 +- src/views/schemaBrowser/statements.ts | 493 ++++++++++++----------- 6 files changed, 311 insertions(+), 243 deletions(-) diff --git a/global.d.ts b/global.d.ts index 372da004..847ec9f1 100644 --- a/global.d.ts +++ b/global.d.ts @@ -35,6 +35,7 @@ interface SQLParm { interface BasicSQLObject { type: string; + tableType: string; schema: string; name: string; specificName: string; diff --git a/package.json b/package.json index ad318bcd..4cb6f7b3 100644 --- a/package.json +++ b/package.json @@ -332,6 +332,11 @@ "title": "Get Indexes", "category": "Db2 for i" }, + { + "command": "vscode-db2i.getObjectLocks", + "title": "Get Object Locks", + "category": "Db2 for i" + }, { "command": "vscode-db2i.clearData", "title": "Clear...", @@ -920,6 +925,11 @@ "when": "viewItem == table || viewItem == schema", "group": "db2workWith@3" }, + { + "command": "vscode-db2i.getObjectLocks", + "when": "viewItem == table || viewItem == view || viewItem == alias || viewItem == constraint || viewItem == function || viewItem == variable || viewItem == index || viewItem == procedure || viewItem == sequence || viewItem == package || viewItem == trigger || viewItem == type", + "group": "db2workWith@5" + }, { "command": "vscode-db2i.clearData", "when": "viewItem == table", diff --git a/src/database/schemas.ts b/src/database/schemas.ts index 6da419d4..eeeca265 100644 --- a/src/database/schemas.ts +++ b/src/database/schemas.ts @@ -56,13 +56,13 @@ export default class Schemas { let filter: PartStatementInfo; // If there are multiple types, we build a union. It's important that the ordering of the columns in the selects are consistant: - // OBJ_TYPE, NAME, TEXT, SYS_NAME, SYS_SCHEMA, SPECNAME, BASE_SCHEMA, BASE_OBJ + // OBJ_TYPE, TABLE_TYPE, NAME, TEXT, SYS_NAME, SYS_SCHEMA, SPECNAME, BASE_SCHEMA, BASE_OBJ for (const type of types) { switch (type) { case `schemas`: selects.push([ - `select '${type}' as OBJ_TYPE, SCHEMA_NAME as NAME, SCHEMA_TEXT as TEXT, SYSTEM_SCHEMA_NAME as SYS_NAME, '' as SYS_SCHEMA, '' as SPECNAME, '' as BASE_SCHEMA, '' as BASE_OBJ`, + `select '${type}' as OBJ_TYPE, '' as TABLE_TYPE, SCHEMA_NAME as NAME, SCHEMA_TEXT as TEXT, SYSTEM_SCHEMA_NAME as SYS_NAME, '' as SYS_SCHEMA, '' as SPECNAME, '' as BASE_SCHEMA, '' as BASE_OBJ`, `from QSYS2.SYSSCHEMAS`, details.filter ? `where UPPER(SCHEMA_NAME) = ? or UPPER(SYSTEM_SCHEMA_NAME) = ?` : ``, ].join(` `)); @@ -78,7 +78,7 @@ export default class Schemas { case `logicals`: filter = getFilterClause(`TABLE_NAME`, details.filter); selects.push([ - `select '${type}' as OBJ_TYPE, TABLE_NAME as NAME, TABLE_TEXT as TEXT, SYSTEM_TABLE_NAME as SYS_NAME, SYSTEM_TABLE_SCHEMA as SYS_SCHEMA, '' as SPECNAME, BASE_TABLE_SCHEMA as BASE_SCHEMA, BASE_TABLE_NAME as BASE_OBJ`, + `select '${type}' as OBJ_TYPE, TABLE_TYPE as TABLE_TYPE, TABLE_NAME as NAME, TABLE_TEXT as TEXT, SYSTEM_TABLE_NAME as SYS_NAME, SYSTEM_TABLE_SCHEMA as SYS_SCHEMA, '' as SPECNAME, BASE_TABLE_SCHEMA as BASE_SCHEMA, BASE_TABLE_NAME as BASE_OBJ`, `from QSYS2.SYSTABLES`, `where TABLE_SCHEMA = ? and TABLE_TYPE in (${typeMap[type].map(item => `'${item}'`).join(`, `)}) ${filter.clause}`, ].join(` `)); @@ -89,7 +89,7 @@ export default class Schemas { case `constraints`: filter = getFilterClause(`CONSTRAINT_NAME`, details.filter); selects.push([ - `select '${type}' as OBJ_TYPE, CONSTRAINT_NAME as NAME, CONSTRAINT_TEXT as TEXT, SYSTEM_TABLE_NAME as SYS_NAME, SYSTEM_TABLE_SCHEMA as SYS_SCHEMA, '' as SPECNAME, TABLE_SCHEMA as BASE_SCHEMA, TABLE_NAME as BASE_OBJ`, + `select '${type}' as OBJ_TYPE, '' as TABLE_TYPE, CONSTRAINT_NAME as NAME, CONSTRAINT_TEXT as TEXT, SYSTEM_TABLE_NAME as SYS_NAME, SYSTEM_TABLE_SCHEMA as SYS_SCHEMA, '' as SPECNAME, TABLE_SCHEMA as BASE_SCHEMA, TABLE_NAME as BASE_OBJ`, `from QSYS2.SYSCST`, `where CONSTRAINT_SCHEMA = ? ${filter.clause}`, ].join(` `)); @@ -100,7 +100,7 @@ export default class Schemas { case `functions`: filter = getFilterClause(`ROUTINE_NAME`, details.filter); selects.push([ - `select '${type}' as OBJ_TYPE, ROUTINE_NAME as NAME, coalesce(ROUTINE_TEXT, LONG_COMMENT) as TEXT, '' as SYS_NAME, '' as SYS_SCHEMA, SPECIFIC_NAME as SPECNAME, '' as BASE_SCHEMA, '' as BASE_OBJ`, + `select '${type}' as OBJ_TYPE, '' as TABLE_TYPE, ROUTINE_NAME as NAME, coalesce(ROUTINE_TEXT, LONG_COMMENT) as TEXT, '' as SYS_NAME, '' as SYS_SCHEMA, SPECIFIC_NAME as SPECNAME, '' as BASE_SCHEMA, '' as BASE_OBJ`, `from QSYS2.SYSFUNCS`, `where ROUTINE_SCHEMA = ? ${filter.clause} and FUNCTION_ORIGIN in ('E','U')`, ].join(` `)); @@ -111,7 +111,7 @@ export default class Schemas { case `variables`: filter = getFilterClause(`VARIABLE_NAME`, details.filter); selects.push([ - `select '${type}' as OBJ_TYPE, VARIABLE_NAME as NAME, VARIABLE_TEXT as TEXT, SYSTEM_VAR_NAME as SYS_NAME, SYSTEM_VAR_SCHEMA as SYS_SCHEMA, '' as SPECNAME, '' as BASE_SCHEMA, '' as BASE_OBJ`, + `select '${type}' as OBJ_TYPE, '' as TABLE_TYPE, VARIABLE_NAME as NAME, VARIABLE_TEXT as TEXT, SYSTEM_VAR_NAME as SYS_NAME, SYSTEM_VAR_SCHEMA as SYS_SCHEMA, '' as SPECNAME, '' as BASE_SCHEMA, '' as BASE_OBJ`, `from QSYS2.SYSVARIABLES`, `where VARIABLE_SCHEMA = ? ${filter.clause}`, ].join(` `)); @@ -122,7 +122,7 @@ export default class Schemas { case `indexes`: filter = getFilterClause(`INDEX_NAME`, details.filter); selects.push([ - `select '${type}' as OBJ_TYPE, INDEX_NAME as NAME, INDEX_TEXT as TEXT, SYSTEM_INDEX_NAME as SYS_NAME, SYSTEM_INDEX_SCHEMA as SYS_SCHEMA, '' as SPECNAME, TABLE_SCHEMA as BASE_SCHEMA, TABLE_NAME as BASE_OBJ`, + `select '${type}' as OBJ_TYPE, '' as TABLE_TYPE, INDEX_NAME as NAME, INDEX_TEXT as TEXT, SYSTEM_INDEX_NAME as SYS_NAME, SYSTEM_INDEX_SCHEMA as SYS_SCHEMA, '' as SPECNAME, TABLE_SCHEMA as BASE_SCHEMA, TABLE_NAME as BASE_OBJ`, `from QSYS2.SYSINDEXES`, `where INDEX_SCHEMA = ? ${filter.clause}`, ].join(` `)); @@ -133,7 +133,7 @@ export default class Schemas { case `procedures`: filter = getFilterClause(`ROUTINE_NAME`, details.filter); selects.push([ - `select '${type}' as OBJ_TYPE, ROUTINE_NAME as NAME, ROUTINE_TEXT as TEXT, '' as SYS_NAME, '' as SYS_SCHEMA, SPECIFIC_NAME as SPECNAME, '' as BASE_SCHEMA, '' as BASE_OBJ`, + `select '${type}' as OBJ_TYPE, '' as TABLE_TYPE, ROUTINE_NAME as NAME, ROUTINE_TEXT as TEXT, '' as SYS_NAME, '' as SYS_SCHEMA, SPECIFIC_NAME as SPECNAME, '' as BASE_SCHEMA, '' as BASE_OBJ`, `from QSYS2.SYSPROCS`, `where ROUTINE_SCHEMA = ? ${filter.clause}`, ].join(` `)); @@ -144,7 +144,7 @@ export default class Schemas { case `sequences`: filter = getFilterClause(`SEQUENCE_NAME`, details.filter); selects.push([ - `select '${type}' as OBJ_TYPE, SEQUENCE_NAME as NAME, SEQUENCE_TEXT as TEXT, SYSTEM_SEQ_NAME as SYS_NAME, SYSTEM_SEQ_SCHEMA as SYS_SCHEMA, '' as SPECNAME, '' as BASE_SCHEMA, '' as BASE_OBJ`, + `select '${type}' as OBJ_TYPE, '' as TABLE_TYPE, SEQUENCE_NAME as NAME, SEQUENCE_TEXT as TEXT, SYSTEM_SEQ_NAME as SYS_NAME, SYSTEM_SEQ_SCHEMA as SYS_SCHEMA, '' as SPECNAME, '' as BASE_SCHEMA, '' as BASE_OBJ`, `from QSYS2.SYSSEQUENCES`, `where SEQUENCE_SCHEMA = ? ${filter.clause}`, ].join(` `)); @@ -154,7 +154,7 @@ export default class Schemas { // case `packages`: // selects.push([ - // `select '${type}' as OBJ_TYPE, PACKAGE_NAME as NAME, PACKAGE_TEXT as TEXT, PROGRAM_SCHEMA as BASE_SCHEMA, PROGRAM_NAME as BASE_OBJ, `, + // `select '${type}' as OBJ_TYPE, '' as TABLE_TYPE, PACKAGE_NAME as NAME, PACKAGE_TEXT as TEXT, PROGRAM_SCHEMA as BASE_SCHEMA, PROGRAM_NAME as BASE_OBJ, `, // ` '' as SYS_SCHEMA, '' as SYS_NAME, '' as SPECNAME`, // `from QSYS2.SQLPACKAGE`, // `where PACKAGE_SCHEMA = '${schema}' ${details.filter ? `and PACKAGE_NAME like '%${filter.clause}%'`: ``}`, @@ -164,7 +164,7 @@ export default class Schemas { case `triggers`: filter = getFilterClause(`TRIGGER_NAME`, details.filter); selects.push([ - `select '${type}' as OBJ_TYPE, TRIGGER_NAME as NAME, TRIGGER_TEXT as TEXT, '' as SYS_NAME, '' as SYS_SCHEMA, '' as SPECNAME, EVENT_OBJECT_SCHEMA as BASE_SCHEMA, EVENT_OBJECT_TABLE as BASE_OBJ`, + `select '${type}' as OBJ_TYPE, '' as TABLE_TYPE, TRIGGER_NAME as NAME, TRIGGER_TEXT as TEXT, '' as SYS_NAME, '' as SYS_SCHEMA, '' as SPECNAME, EVENT_OBJECT_SCHEMA as BASE_SCHEMA, EVENT_OBJECT_TABLE as BASE_OBJ`, `from QSYS2.SYSTRIGGERS`, `where TRIGGER_SCHEMA = ? ${filter.clause}`, ].join(` `)); @@ -175,7 +175,7 @@ export default class Schemas { case `types`: filter = getFilterClause(`USER_DEFINED_TYPE_NAME`, details.filter); selects.push([ - `select '${type}' as OBJ_TYPE, USER_DEFINED_TYPE_NAME as NAME, TYPE_TEXT as TEXT, SYSTEM_TYPE_NAME as SYS_NAME, SYSTEM_TYPE_SCHEMA as SYS_SCHEMA, '' as SPECNAME, '' as BASE_SCHEMA, '' as BASE_OBJ`, + `select '${type}' as OBJ_TYPE, '' as TABLE_TYPE, USER_DEFINED_TYPE_NAME as NAME, TYPE_TEXT as TEXT, SYSTEM_TYPE_NAME as SYS_NAME, SYSTEM_TYPE_SCHEMA as SYS_SCHEMA, '' as SPECNAME, '' as BASE_SCHEMA, '' as BASE_OBJ`, `from QSYS2.SYSTYPES`, `where USER_DEFINED_TYPE_SCHEMA = ? ${filter.clause}`, ].join(` `)); @@ -199,6 +199,7 @@ export default class Schemas { return objects.map(object => ({ type: object.OBJ_TYPE, + tableType: object.TABLE_TYPE, schema, name: object.NAME || undefined, specificName: object.SPECNAME || undefined, diff --git a/src/views/schemaBrowser/contributes.json b/src/views/schemaBrowser/contributes.json index 6c8da753..38e90fd1 100644 --- a/src/views/schemaBrowser/contributes.json +++ b/src/views/schemaBrowser/contributes.json @@ -49,6 +49,11 @@ "title": "Get Indexes", "category": "Db2 for i" }, + { + "command": "vscode-db2i.getObjectLocks", + "title": "Get Object Locks", + "category": "Db2 for i" + }, { "command": "vscode-db2i.clearData", "title": "Clear...", @@ -157,6 +162,11 @@ "when": "viewItem == table || viewItem == schema", "group": "db2workWith@3" }, + { + "command": "vscode-db2i.getObjectLocks", + "when": "viewItem == table || viewItem == view || viewItem == alias || viewItem == constraint || viewItem == function || viewItem == variable || viewItem == index || viewItem == procedure || viewItem == sequence || viewItem == package || viewItem == trigger || viewItem == type", + "group": "db2workWith@5" + }, { "command": "vscode-db2i.clearData", "when": "viewItem == table", diff --git a/src/views/schemaBrowser/index.ts b/src/views/schemaBrowser/index.ts index 4503ced3..eb7837df 100644 --- a/src/views/schemaBrowser/index.ts +++ b/src/views/schemaBrowser/index.ts @@ -10,7 +10,7 @@ import Configuration from "../../configuration"; import Types from "../types"; import Statement from "../../database/statement"; import { copyUI } from "./copyUI"; -import { getAdvisedIndexesStatement, getIndexesStatement, getMTIStatement } from "./statements"; +import { getAdvisedIndexesStatement, getIndexesStatement, getMTIStatement, getObjectLocksStatement } from "./statements"; const viewItem = { "tables": `table`, @@ -187,6 +187,17 @@ export default class schemaBrowser { } }), + vscode.commands.registerCommand(`vscode-db2i.getObjectLocks`, async (object: SQLObject) => { + if (object) { + const content = getObjectLocksStatement(object.schema, object.name, object.type.toUpperCase(), object.tableType); + vscode.commands.executeCommand(`vscode-db2i.runEditorStatement`, { + content, + qualifier: `statement`, + open: false, + }); + } + }), + vscode.commands.registerCommand(`vscode-db2i.advisedIndexes`, async (object: SQLObject|SchemaItem) => { //table if (object) { let content: string|undefined; @@ -546,6 +557,7 @@ class SQLObject extends vscode.TreeItem { name: string; specificName: string; type: string; + tableType: string; system: { schema: string; name: string; @@ -562,6 +574,7 @@ class SQLObject extends vscode.TreeItem { this.specificName = item.specificName; // Only applies to routines this.system = item.system; this.type = type; + this.tableType = item.tableType; this.description = item.text; // For functions and procedures, set a tooltip that includes the specific name if (Schemas.isRoutineType(this.type)) { diff --git a/src/views/schemaBrowser/statements.ts b/src/views/schemaBrowser/statements.ts index 1a07526c..f63e998a 100644 --- a/src/views/schemaBrowser/statements.ts +++ b/src/views/schemaBrowser/statements.ts @@ -1,237 +1,270 @@ export function getIndexesStatement(schema: string, name: string) { -return ` --- -with X as ( - select max(INDEX_NAME) NAME, SYSTEM_INDEX_NAME SYSNAME, max(INDEX_SCHEMA) SCHEMA, - SYSTEM_INDEX_SCHEMA SYSSCHEMA, - case count(distinct INDEX_PARTITION) - when 1 then max(INDEX_PARTITION) - else NULL - end PARTITION, max(INDEX_TYPE) TYPE, max(INDEX_OWNER) OWNER, max(INDEX_VALID) VALID, - min(CREATE_TIMESTAMP) CREATED, max(LAST_BUILD_TIMESTAMP) BUILT, max(LAST_QUERY_USE) LQU, - max(LAST_STATISTICS_USE) LSU, sum(QUERY_USE_COUNT) QUC, sum(QUERY_STATISTICS_COUNT) QSC, - max(LAST_USED_TIMESTAMP) USED, max(DAYS_USED_COUNT) DUC, max(LAST_RESET_TIMESTAMP) RESET, - max(NUMBER_KEYS) KEYS, max(INDEX_SIZE) SIZE, max(NUMBER_PAGES) PAGES, - max(LOGICAL_PAGE_SIZE) PAGESIZE, max(UNIQUE) UNIQUE, max(MAXIMUM_KEY_LENGTH) MAXKEYLEN, - max(NUMBER_KEY_COLUMNS) KEYCOLCOUNT, max(COLUMN_NAMES) COLUMNS, - max(UNIQUE_PARTIAL_KEY_VALUES) UPKV, max(OVERFLOW_VALUES) OVERFLOW, - max(EVI_CODE_SIZE) EVISIZE, max(SPARSE) SPARSE, max(DERIVED_KEY) DERIVEDKEY, - max(PARTITIONED) PARTITIONED, max(ACCPTH_TYPE) ACCPTHTYPE, max(SORT_SEQUENCE) SORTSEQ, - max(LANGUAGE_IDENTIFIER) LANGID, max(ESTIMATED_BUILD_TIME) ESTBUILDTIME, - max(INDEX_HELD) HELD, max(MAINTENANCE) MAINTENANCE, - max(DELAYED_MAINT_KEYS) DELAYEDMAINTKEYS, max(RECOVERY) RECOVERY, - max(LOGICAL_READS) LOGICALREADS, 0 PHYSICALREADS, max(INDEX_TEXT) TEXT, - max(SEARCH_CONDITION) SEARCHCOND, max(SEARCH_CONDITION_HAS_UDF) SEARCHCONDHASUDF, + return ` + -- + with X as ( + select max(INDEX_NAME) NAME, SYSTEM_INDEX_NAME SYSNAME, max(INDEX_SCHEMA) SCHEMA, + SYSTEM_INDEX_SCHEMA SYSSCHEMA, + case count(distinct INDEX_PARTITION) + when 1 then max(INDEX_PARTITION) + else NULL + end PARTITION, max(INDEX_TYPE) TYPE, max(INDEX_OWNER) OWNER, max(INDEX_VALID) VALID, + min(CREATE_TIMESTAMP) CREATED, max(LAST_BUILD_TIMESTAMP) BUILT, max(LAST_QUERY_USE) LQU, + max(LAST_STATISTICS_USE) LSU, sum(QUERY_USE_COUNT) QUC, sum(QUERY_STATISTICS_COUNT) QSC, + max(LAST_USED_TIMESTAMP) USED, max(DAYS_USED_COUNT) DUC, max(LAST_RESET_TIMESTAMP) RESET, + max(NUMBER_KEYS) KEYS, max(INDEX_SIZE) SIZE, max(NUMBER_PAGES) PAGES, + max(LOGICAL_PAGE_SIZE) PAGESIZE, max(UNIQUE) UNIQUE, max(MAXIMUM_KEY_LENGTH) MAXKEYLEN, + max(NUMBER_KEY_COLUMNS) KEYCOLCOUNT, max(COLUMN_NAMES) COLUMNS, + max(UNIQUE_PARTIAL_KEY_VALUES) UPKV, max(OVERFLOW_VALUES) OVERFLOW, + max(EVI_CODE_SIZE) EVISIZE, max(SPARSE) SPARSE, max(DERIVED_KEY) DERIVEDKEY, + max(PARTITIONED) PARTITIONED, max(ACCPTH_TYPE) ACCPTHTYPE, max(SORT_SEQUENCE) SORTSEQ, + max(LANGUAGE_IDENTIFIER) LANGID, max(ESTIMATED_BUILD_TIME) ESTBUILDTIME, + max(INDEX_HELD) HELD, max(MAINTENANCE) MAINTENANCE, + max(DELAYED_MAINT_KEYS) DELAYEDMAINTKEYS, max(RECOVERY) RECOVERY, + max(LOGICAL_READS) LOGICALREADS, 0 PHYSICALREADS, max(INDEX_TEXT) TEXT, + max(SEARCH_CONDITION) SEARCHCOND, max(SEARCH_CONDITION_HAS_UDF) SEARCHCONDHASUDF, + case + when max(TABLE_NAME) = min(TABLE_NAME) then max(TABLE_NAME) + else NULL + end TABNAME, + case + when max(SYSTEM_TABLE_SCHEMA) = min(SYSTEM_TABLE_SCHEMA) then max(SYSTEM_TABLE_SCHEMA) + else NULL + end SYSTABSCHEMA, + case + when max(TABLE_PARTITION) = min(TABLE_PARTITION) then max(TABLE_PARTITION) + else NULL + end TABPART, + case + when max(SYSTEM_TABLE_NAME) = min(SYSTEM_TABLE_NAME) then max(SYSTEM_TABLE_NAME) + else NULL + end SYSTABNAME, max(TABLE_SCHEMA) TABSCHEMA, max(SORT_SEQUENCE_NAME) SORTSEQNAME, + max(SORT_SEQUENCE_SCHEMA) SORTSEQSCHEMA, max(MEDIA_PREFERENCE) MEDIAPREF, + max(KEEP_IN_MEMORY) KIM, sum(RANDOM_READS) RANDOMREADS, + max(LAST_BUILD_TIME) LASTBUILDTIME, max(LAST_BUILD_KEYS) LASTBUILDKEYS, + max(LAST_BUILD_DEGREE) LASTBUILDDEGREE, sum(SEQUENTIAL_READS) SEQREADS, + max(INCLUDE_EXPRESSION) INCEXPR, + case + when max(PARTITIONED) = 'YES' then count(*) + else 1 + end IDXCOUNT + from QSYS2.SYSPARTITIONINDEXES + where + + TABLE_SCHEMA = '${schema}' and + TABLE_NAME = '${name}' and + + INDEX_NAME not like '%MAINTAINED TEMPORARY INDEXES%' + group by SYSTEM_INDEX_SCHEMA, INDEX_NAME, SYSTEM_INDEX_NAME + union all + select MTI_NAME, cast(null as char(10)), cast(null as varchar(128)), cast(null as char(10)), cast(null as varchar(128)), + 'TEMPORARY', 'SQL QUERY ENGINE', case state when 'VALID' then 'YES' else 'NO' end, + CREATE_TIME, LAST_BUILD_START_TIME, cast(null as timestamp), cast(null as timestamp), + cast(null as bigint), cast(null as bigint), cast(null as timestamp), + cast(null as integer), cast(null as timestamp), KEYS, MTI_SIZE, cast(null as bigint), + cast(null as integer), cast(null as varchar(21)), cast(null as integer), KEYS, + varchar(KEY_DEFINITION, 1024), cast(null as varchar(96)), cast(null as integer), cast(null as integer), + SPARSE, cast(null as varchar(3)), cast(null as varchar(20)), cast(null as varchar(4)), + cast(null as varchar(12)), cast(null as char(3)), case when LAST_BUILD_START_TIME is not null + and LAST_BUILD_END_TIME is not null then + integer(timestampdiff_big(2, cast(LAST_BUILD_END_TIME - LAST_BUILD_START_TIME as char(22)))) + else cast(null as integer) end, cast(null as varchar(3)), cast(null as varchar(11)), + cast(null as integer), cast(null as varchar(10)), cast(null as bigint), cast(null as integer), + cast(null as vargraphic(50)), cast(null as vargraphic(1024)), cast(null as varchar(3)), + TABLE_NAME, LIBRARY_NAME, cast(null as varchar(128)), cast(null as char(10)), TABLE_SCHEMA, + cast(null as char(10)), cast(null as char(10)), cast(null as varchar(3)), cast(null as varchar(3)), + cast(null as bigint), case when LAST_BUILD_START_TIME is not null + and LAST_BUILD_END_TIME is not null then + integer(timestampdiff_big(2, cast(LAST_BUILD_END_TIME - LAST_BUILD_START_TIME as char(22)))) + else cast(null as integer) end, cast(null as bigint), cast(null as smallint), + cast(null as bigint), cast(null as vargraphic(1024)), cast(null as integer) + from table ( + qsys2.mti_info(TABLE_SCHEMA => '${schema}', TABLE_NAME => '${name}') + ) + ) + select QSYS2.DELIMIT_NAME(NAME) "Index Name", + case TYPE + when 'INDEX' then 'Index' + when 'LOGICAL' then 'Keyed Logical File' + when 'PHYSICAL' then 'Keyed Physical File' + when 'PRIMARY KEY' then 'Primary Key Constraint' + when 'UNIQUE' then 'Unique Key Constraint' + when 'FOREIGN KEY' then 'Foreign Key Constraint' + when 'TEMPORARY' then 'Temporary Index' + else cast(TYPE as varchar(11)) + end "Type", + COLUMNS "Key Columns", + trim(VARCHAR_FORMAT(SIZE, '999G999G999G999G999')) "Size", + case VALID + when 'YES' then 'Yes' + when 'NO' then 'No' + else cast(VALID as varchar(3)) + end "Valid", + OWNER "Owner", + VARCHAR_FORMAT(CREATED, 'MM/DD/YYYY HH:MI:SS AM') "Date Created", + VARCHAR_FORMAT(BUILT, 'MM/DD/YYYY HH:MI:SS AM') "Last Build", case - when max(TABLE_NAME) = min(TABLE_NAME) then max(TABLE_NAME) - else NULL - end TABNAME, + when PARTITION is NULL then '' + else QSYS2.DELIMIT_NAME(PARTITION) + end "Partition", + VARCHAR_FORMAT(LQU, 'MM/DD/YYYY HH:MI:SS AM') "Last Query Use", + VARCHAR_FORMAT(LSU, 'MM/DD/YYYY HH:MI:SS AM') "Last Query Statistics Use", + trim(VARCHAR_FORMAT(QUC, '999G999G999G999G999')) "Query Use Count", + trim(VARCHAR_FORMAT(QSC, '999G999G999G999G999')) "Query Statistics Use Count", + VARCHAR_FORMAT(USED, 'MM/DD/YYYY HH:MI:SS AM') "Last Used", + trim(VARCHAR_FORMAT(DUC, '999G999G999G999G999')) "Days Used Count", + VARCHAR_FORMAT(RESET, 'MM/DD/YYYY') "Days Used Count Reset Date", + ACCPTHTYPE "Maximum Size", case - when max(SYSTEM_TABLE_SCHEMA) = min(SYSTEM_TABLE_SCHEMA) then max(SYSTEM_TABLE_SCHEMA) - else NULL - end SYSTABSCHEMA, + when UNIQUE is NULL then '' + when UNIQUE = 'UNIQUE' then 'Unique' + when UNIQUE = 'UNIQUE WHERE NOT NULL' then 'Unique where not null' + else cast(UNIQUE as varchar(21)) + end "Duplicate Key Order", + trim(VARCHAR_FORMAT(PAGESIZE, '999G999G999G999G999')) "Logical Page Size", case - when max(TABLE_PARTITION) = min(TABLE_PARTITION) then max(TABLE_PARTITION) - else NULL - end TABPART, + when EVISIZE is NULL then '' + when EVISIZE = 1 then '255' + when EVISIZE = 2 then '65,535' + when EVISIZE = 4 then '2,147,483,647' + else cast(EVISIZE as varchar(128)) + end "EVI Distinct Values", + case SORTSEQ + when 'BY HEX VALUE' then 'By hex value' + else cast(SORTSEQ as varchar(12)) + end "Sort Sequence", LANGID "Language Identifier", case - when max(SYSTEM_TABLE_NAME) = min(SYSTEM_TABLE_NAME) then max(SYSTEM_TABLE_NAME) - else NULL - end SYSTABNAME, max(TABLE_SCHEMA) TABSCHEMA, max(SORT_SEQUENCE_NAME) SORTSEQNAME, - max(SORT_SEQUENCE_SCHEMA) SORTSEQSCHEMA, max(MEDIA_PREFERENCE) MEDIAPREF, - max(KEEP_IN_MEMORY) KIM, sum(RANDOM_READS) RANDOMREADS, - max(LAST_BUILD_TIME) LASTBUILDTIME, max(LAST_BUILD_KEYS) LASTBUILDKEYS, - max(LAST_BUILD_DEGREE) LASTBUILDDEGREE, sum(SEQUENTIAL_READS) SEQREADS, - max(INCLUDE_EXPRESSION) INCEXPR, + when PARTITIONED is NULL then '' + when PARTITIONED = 'NO' then 'Yes' + when PARTITIONED = 'YES' then 'No' + else cast(PARTITIONED as varchar(20)) + end "Spanning", + case KIM + when 'YES' then 'Yes' + when 'NO' then 'No' + else cast(KIM as varchar(3)) + end "Keep in Memory", + case MEDIAPREF + when 'ANY' then 'Any' + else cast(MEDIAPREF as varchar(3)) + end "Media Preference", RANDOMREADS "Random Reads", SEQREADS "Sequential Reads", + ESTBUILDTIME "Estimated Rebuild Time", LASTBUILDTIME "Last Rebuild Time", + KEYS "Current Key Values", LASTBUILDKEYS "Last Rebuild Key Count", + LASTBUILDDEGREE "Last Rebuild Parallel Degree", case - when max(PARTITIONED) = 'YES' then count(*) - else 1 - end IDXCOUNT - from QSYS2.SYSPARTITIONINDEXES - where - - TABLE_SCHEMA = '${schema}' and - TABLE_NAME = '${name}' and - - INDEX_NAME not like '%MAINTAINED TEMPORARY INDEXES%' - group by SYSTEM_INDEX_SCHEMA, INDEX_NAME, SYSTEM_INDEX_NAME - union all - select MTI_NAME, cast(null as char(10)), cast(null as varchar(128)), cast(null as char(10)), cast(null as varchar(128)), - 'TEMPORARY', 'SQL QUERY ENGINE', case state when 'VALID' then 'YES' else 'NO' end, - CREATE_TIME, LAST_BUILD_START_TIME, cast(null as timestamp), cast(null as timestamp), - cast(null as bigint), cast(null as bigint), cast(null as timestamp), - cast(null as integer), cast(null as timestamp), KEYS, MTI_SIZE, cast(null as bigint), - cast(null as integer), cast(null as varchar(21)), cast(null as integer), KEYS, - varchar(KEY_DEFINITION, 1024), cast(null as varchar(96)), cast(null as integer), cast(null as integer), - SPARSE, cast(null as varchar(3)), cast(null as varchar(20)), cast(null as varchar(4)), - cast(null as varchar(12)), cast(null as char(3)), case when LAST_BUILD_START_TIME is not null - and LAST_BUILD_END_TIME is not null then - integer(timestampdiff_big(2, cast(LAST_BUILD_END_TIME - LAST_BUILD_START_TIME as char(22)))) - else cast(null as integer) end, cast(null as varchar(3)), cast(null as varchar(11)), - cast(null as integer), cast(null as varchar(10)), cast(null as bigint), cast(null as integer), - cast(null as vargraphic(50)), cast(null as vargraphic(1024)), cast(null as varchar(3)), - TABLE_NAME, LIBRARY_NAME, cast(null as varchar(128)), cast(null as char(10)), TABLE_SCHEMA, - cast(null as char(10)), cast(null as char(10)), cast(null as varchar(3)), cast(null as varchar(3)), - cast(null as bigint), case when LAST_BUILD_START_TIME is not null - and LAST_BUILD_END_TIME is not null then - integer(timestampdiff_big(2, cast(LAST_BUILD_END_TIME - LAST_BUILD_START_TIME as char(22)))) - else cast(null as integer) end, cast(null as bigint), cast(null as smallint), - cast(null as bigint), cast(null as vargraphic(1024)), cast(null as integer) - from table ( - qsys2.mti_info(TABLE_SCHEMA => '${schema}', TABLE_NAME => '${name}') - ) - ) - select QSYS2.DELIMIT_NAME(NAME) "Index Name", - case TYPE - when 'INDEX' then 'Index' - when 'LOGICAL' then 'Keyed Logical File' - when 'PHYSICAL' then 'Keyed Physical File' - when 'PRIMARY KEY' then 'Primary Key Constraint' - when 'UNIQUE' then 'Unique Key Constraint' - when 'FOREIGN KEY' then 'Foreign Key Constraint' - when 'TEMPORARY' then 'Temporary Index' - else cast(TYPE as varchar(11)) - end "Type", - COLUMNS "Key Columns", - trim(VARCHAR_FORMAT(SIZE, '999G999G999G999G999')) "Size", - case VALID - when 'YES' then 'Yes' - when 'NO' then 'No' - else cast(VALID as varchar(3)) - end "Valid", - OWNER "Owner", - VARCHAR_FORMAT(CREATED, 'MM/DD/YYYY HH:MI:SS AM') "Date Created", - VARCHAR_FORMAT(BUILT, 'MM/DD/YYYY HH:MI:SS AM') "Last Build", - case - when PARTITION is NULL then '' - else QSYS2.DELIMIT_NAME(PARTITION) - end "Partition", - VARCHAR_FORMAT(LQU, 'MM/DD/YYYY HH:MI:SS AM') "Last Query Use", - VARCHAR_FORMAT(LSU, 'MM/DD/YYYY HH:MI:SS AM') "Last Query Statistics Use", - trim(VARCHAR_FORMAT(QUC, '999G999G999G999G999')) "Query Use Count", - trim(VARCHAR_FORMAT(QSC, '999G999G999G999G999')) "Query Statistics Use Count", - VARCHAR_FORMAT(USED, 'MM/DD/YYYY HH:MI:SS AM') "Last Used", - trim(VARCHAR_FORMAT(DUC, '999G999G999G999G999')) "Days Used Count", - VARCHAR_FORMAT(RESET, 'MM/DD/YYYY') "Days Used Count Reset Date", - ACCPTHTYPE "Maximum Size", - case - when UNIQUE is NULL then '' - when UNIQUE = 'UNIQUE' then 'Unique' - when UNIQUE = 'UNIQUE WHERE NOT NULL' then 'Unique where not null' - else cast(UNIQUE as varchar(21)) - end "Duplicate Key Order", - trim(VARCHAR_FORMAT(PAGESIZE, '999G999G999G999G999')) "Logical Page Size", - case - when EVISIZE is NULL then '' - when EVISIZE = 1 then '255' - when EVISIZE = 2 then '65,535' - when EVISIZE = 4 then '2,147,483,647' - else cast(EVISIZE as varchar(128)) - end "EVI Distinct Values", - case SORTSEQ - when 'BY HEX VALUE' then 'By hex value' - else cast(SORTSEQ as varchar(12)) - end "Sort Sequence", LANGID "Language Identifier", - case - when PARTITIONED is NULL then '' - when PARTITIONED = 'NO' then 'Yes' - when PARTITIONED = 'YES' then 'No' - else cast(PARTITIONED as varchar(20)) - end "Spanning", - case KIM - when 'YES' then 'Yes' - when 'NO' then 'No' - else cast(KIM as varchar(3)) - end "Keep in Memory", - case MEDIAPREF - when 'ANY' then 'Any' - else cast(MEDIAPREF as varchar(3)) - end "Media Preference", RANDOMREADS "Random Reads", SEQREADS "Sequential Reads", - ESTBUILDTIME "Estimated Rebuild Time", LASTBUILDTIME "Last Rebuild Time", - KEYS "Current Key Values", LASTBUILDKEYS "Last Rebuild Key Count", - LASTBUILDDEGREE "Last Rebuild Parallel Degree", - case - when TABNAME is NULL then NULL - else QSYS2.DELIMIT_NAME(TABNAME) - end "Table Name", SYSTABNAME "Table System Name", - case - when TABSCHEMA is NULL then NULL - else QSYS2.DELIMIT_NAME(TABSCHEMA) - end "Table Schema", SYSTABSCHEMA "Table System Schema", TABPART "Table Partition", - trim(VARCHAR_FORMAT(PAGES, '999G999G999G999G999')) "Current Allocated Pages", - DELAYEDMAINTKEYS "Delayed Maintenance Keys", - case DERIVEDKEY - when 'YES' then 'Yes' - when 'NO' then 'No' - else cast(DERIVEDKEY as varchar(3)) - end "Derived Key", - case HELD - when 'YES' then 'Yes' - when 'NO' then 'No' - else cast(HELD as varchar(3)) - end "Held", - case INCEXPR - when 'YES' then 'Yes' - when 'NO' then 'No' - else cast(INCEXPR as varchar(3)) - end "INCLUDE Expression", LOGICALREADS "Index Logical Reads", - case - when MAINTENANCE is NULL then '' - when MAINTENANCE = 'REBUILD' then 'Rebuild' - when MAINTENANCE = 'DELAYED' then 'Delayed' - when MAINTENANCE = 'DO NOT WAIT' then 'Do not wait' - else cast(MAINTENANCE as varchar(11)) - end "Maintenance", MAXKEYLEN "Maximum Key Length", KEYCOLCOUNT "Key Column Count", - OVERFLOW "Overflow Values", - case - when RECOVERY is NULL then '' - when RECOVERY = 'AFTER IPL' then 'After IPL' - when RECOVERY = 'DURING IPL' then 'During IPL' - when RECOVERY = 'NEXT OPEN' then 'Next open' - else cast(RECOVERY as varchar(10)) - end "Recovery", SORTSEQNAME "Sort Sequence Name", SORTSEQSCHEMA "Sort Sequence Schema", - case SPARSE - when 'YES' then 'Yes' - when 'NO' then 'No' - else cast(SPARSE as varchar(3)) - end "Sparse", UPKV "Unique Partial Key Values", SEARCHCOND "WHERE Clause", - SEARCHCONDHASUDF "WHERE Clause Has UDF", - case - when TEXT is NULL then '' - else trim(TEXT) - end "Text", - SYSNAME "Index System Name", - case - when SCHEMA is NULL then NULL - else QSYS2.DELIMIT_NAME(SCHEMA) - end "Schema", SYSSCHEMA "System Schema" - - from X - order by 1 asc -`; -} - -export function getAdvisedIndexesStatement(schema: string, name?: string) { - return [ - `select KEY_COLUMNS_ADVISED, Times_Advised, Most_Expensive_Query, Average_Query_Estimate,`, - ` Last_Advised, MTI_USED_FOR_STATS, LAST_MTI_USED_FOR_STATS, Table_Size, MTI_USED, MTI_CREATED,`, - ` LAST_MTI_USED, System_Table_Schema, Estimated_Creation_Time, Logical_Page_Size, INDEX_TYPE,`, - ` TABLE_NAME, TABLE_SCHEMA, SYSTEM_TABLE_NAME, PARTITION_NAME, LOGICAL_PAGE_SIZE,`, - ` NLSS_TABLE_NAME, NLSS_TABLE_SCHEMA, MAX_ROW`, - `from qsys2.condidxa where`, - ...(name ? [`TABLE_NAME = '${name}' and`] : []), - ` Table_Schema = '${schema}'`, - ` order by Times_Advised desc`, - ].join(` `); -} - -export function getMTIStatement(schema: string, table: string = `*ALL`) { - return [ - `select * `, - `from table (`, - ` qsys2.mti_info(TABLE_SCHEMA => '${schema}', TABLE_NAME => '${table}')`, - `)`, - `order by key_definition`, - ].join(` `); -} \ No newline at end of file + when TABNAME is NULL then NULL + else QSYS2.DELIMIT_NAME(TABNAME) + end "Table Name", SYSTABNAME "Table System Name", + case + when TABSCHEMA is NULL then NULL + else QSYS2.DELIMIT_NAME(TABSCHEMA) + end "Table Schema", SYSTABSCHEMA "Table System Schema", TABPART "Table Partition", + trim(VARCHAR_FORMAT(PAGES, '999G999G999G999G999')) "Current Allocated Pages", + DELAYEDMAINTKEYS "Delayed Maintenance Keys", + case DERIVEDKEY + when 'YES' then 'Yes' + when 'NO' then 'No' + else cast(DERIVEDKEY as varchar(3)) + end "Derived Key", + case HELD + when 'YES' then 'Yes' + when 'NO' then 'No' + else cast(HELD as varchar(3)) + end "Held", + case INCEXPR + when 'YES' then 'Yes' + when 'NO' then 'No' + else cast(INCEXPR as varchar(3)) + end "INCLUDE Expression", LOGICALREADS "Index Logical Reads", + case + when MAINTENANCE is NULL then '' + when MAINTENANCE = 'REBUILD' then 'Rebuild' + when MAINTENANCE = 'DELAYED' then 'Delayed' + when MAINTENANCE = 'DO NOT WAIT' then 'Do not wait' + else cast(MAINTENANCE as varchar(11)) + end "Maintenance", MAXKEYLEN "Maximum Key Length", KEYCOLCOUNT "Key Column Count", + OVERFLOW "Overflow Values", + case + when RECOVERY is NULL then '' + when RECOVERY = 'AFTER IPL' then 'After IPL' + when RECOVERY = 'DURING IPL' then 'During IPL' + when RECOVERY = 'NEXT OPEN' then 'Next open' + else cast(RECOVERY as varchar(10)) + end "Recovery", SORTSEQNAME "Sort Sequence Name", SORTSEQSCHEMA "Sort Sequence Schema", + case SPARSE + when 'YES' then 'Yes' + when 'NO' then 'No' + else cast(SPARSE as varchar(3)) + end "Sparse", UPKV "Unique Partial Key Values", SEARCHCOND "WHERE Clause", + SEARCHCONDHASUDF "WHERE Clause Has UDF", + case + when TEXT is NULL then '' + else trim(TEXT) + end "Text", + SYSNAME "Index System Name", + case + when SCHEMA is NULL then NULL + else QSYS2.DELIMIT_NAME(SCHEMA) + end "Schema", SYSSCHEMA "System Schema" + + from X + order by 1 asc + `; + } + + export function getAdvisedIndexesStatement(schema: string, name?: string) { + return [ + `select KEY_COLUMNS_ADVISED, Times_Advised, Most_Expensive_Query, Average_Query_Estimate,`, + ` Last_Advised, MTI_USED_FOR_STATS, LAST_MTI_USED_FOR_STATS, Table_Size, MTI_USED, MTI_CREATED,`, + ` LAST_MTI_USED, System_Table_Schema, Estimated_Creation_Time, Logical_Page_Size, INDEX_TYPE,`, + ` TABLE_NAME, TABLE_SCHEMA, SYSTEM_TABLE_NAME, PARTITION_NAME, LOGICAL_PAGE_SIZE,`, + ` NLSS_TABLE_NAME, NLSS_TABLE_SCHEMA, MAX_ROW`, + `from qsys2.condidxa where`, + ...(name ? [`TABLE_NAME = '${name}' and`] : []), + ` Table_Schema = '${schema}'`, + ` order by Times_Advised desc`, + ].join(` `); + } + + export function getMTIStatement(schema: string, table: string = `*ALL`) { + return [ + `select * `, + `from table (`, + ` qsys2.mti_info(TABLE_SCHEMA => '${schema}', TABLE_NAME => '${table}')`, + `)`, + `order by key_definition`, + ].join(` `); + } + + export function getObjectLocksStatement(schema: string, table: string, objectType: string, tableType: string): string { + let sql: string = ` + select + system_table_member "Member", + member_lock_type "Member Lock Type", + lock_state "Lock State", + lock_status "Lock Status", + lock_scope "Scope", + substr(job_name, locate_in_string(job_name, '/', -1) + 1) "Job Name", + substr(job_name, locate_in_string(job_name, '/', 1) + 1, locate_in_string(job_name, '/', -1) - locate_in_string(job_name, '/', 1) - 1) "Job User", + substr(job_name, 1, locate_in_string(job_name, '/', 1) - 1) "Job Number", + thread_id "Thread", + lock_space_id "Lock Space", + lock_count "Lock Count", + program_library_name "Program Library", + program_name "Program Name", + module_library_name "Module Library", + module_name "Module Name", + procedure_name "Procedure Name", + statement_id "Statement ID", + machine_instruction "Instruction" + from qsys2.object_lock_info + where object_schema = '${schema}' + and object_name = '${table}' + `; + if (objectType === 'TABLE' && tableType != 'T') { + sql += ` and object_type = '*FILE'`; + } else { + sql += ` and sql_object_type = '${objectType.toUpperCase()}'`; + } + return sql; + } \ No newline at end of file