Skip to content

Commit

Permalink
Merge pull request #312 from janfh/feature/view_authorities
Browse files Browse the repository at this point in the history
Right click option on SQL objects to view authorities
  • Loading branch information
worksofliam authored Jan 7, 2025
2 parents cc019bb + 1877ee3 commit 9e435e8
Show file tree
Hide file tree
Showing 6 changed files with 81 additions and 13 deletions.
1 change: 1 addition & 0 deletions global.d.ts
Original file line number Diff line number Diff line change
Expand Up @@ -35,6 +35,7 @@ interface SQLParm {

interface BasicSQLObject {
type: string;
tableType: string;
schema: string;
name: string;
specificName: string;
Expand Down
10 changes: 10 additions & 0 deletions package.json
Original file line number Diff line number Diff line change
Expand Up @@ -332,6 +332,11 @@
"title": "Get Indexes",
"category": "Db2 for i"
},
{
"command": "vscode-db2i.getAuthorities",
"title": "Get Authorities",
"category": "Db2 for i"
},
{
"command": "vscode-db2i.clearData",
"title": "Clear...",
Expand Down Expand Up @@ -920,6 +925,11 @@
"when": "viewItem == table || viewItem == schema",
"group": "db2workWith@3"
},
{
"command": "vscode-db2i.getAuthorities",
"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@4"
},
{
"command": "vscode-db2i.clearData",
"when": "viewItem == table",
Expand Down
25 changes: 13 additions & 12 deletions src/database/schemas.ts
Original file line number Diff line number Diff line change
Expand Up @@ -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(` `));
Expand All @@ -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(` `));
Expand All @@ -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(` `));
Expand All @@ -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(` `));
Expand All @@ -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(` `));
Expand All @@ -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(` `));
Expand All @@ -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(` `));
Expand All @@ -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(` `));
Expand All @@ -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}%'`: ``}`,
Expand All @@ -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(` `));
Expand All @@ -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(` `));
Expand All @@ -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,
Expand Down
10 changes: 10 additions & 0 deletions src/views/schemaBrowser/contributes.json
Original file line number Diff line number Diff line change
Expand Up @@ -49,6 +49,11 @@
"title": "Get Indexes",
"category": "Db2 for i"
},
{
"command": "vscode-db2i.getAuthorities",
"title": "Get Authorities",
"category": "Db2 for i"
},
{
"command": "vscode-db2i.clearData",
"title": "Clear...",
Expand Down Expand Up @@ -157,6 +162,11 @@
"when": "viewItem == table || viewItem == schema",
"group": "db2workWith@3"
},
{
"command": "vscode-db2i.getAuthorities",
"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@4"
},
{
"command": "vscode-db2i.clearData",
"when": "viewItem == table",
Expand Down
15 changes: 14 additions & 1 deletion src/views/schemaBrowser/index.ts
Original file line number Diff line number Diff line change
Expand Up @@ -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, getAuthoritiesStatement } from "./statements";

const viewItem = {
"tables": `table`,
Expand Down Expand Up @@ -187,6 +187,17 @@ export default class schemaBrowser {
}
}),

vscode.commands.registerCommand(`vscode-db2i.getAuthorities`, async (object: SQLObject) => {
if (object) {
const content = getAuthoritiesStatement(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;
Expand Down Expand Up @@ -546,6 +557,7 @@ class SQLObject extends vscode.TreeItem {
name: string;
specificName: string;
type: string;
tableType: string;
system: {
schema: string;
name: string;
Expand All @@ -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)) {
Expand Down
33 changes: 33 additions & 0 deletions src/views/schemaBrowser/statements.ts
Original file line number Diff line number Diff line change
Expand Up @@ -234,4 +234,37 @@ export function getMTIStatement(schema: string, table: string = `*ALL`) {
`)`,
`order by key_definition`,
].join(` `);
}

export function getAuthoritiesStatement(schema: string, table: string, objectType: string, tableType: string): string {
let sql: string = `
select
authorization_name "User profile name",
object_authority "Object authority",
owner "Object owner",
authorization_list "Authorization list",
primary_group "Primary group",
authorization_list_management "Authorization list management",
object_owner "User is object owner",
object_operational "Object operational authority",
object_management "Object management authority",
object_existence "Object existence authority",
object_alter "Object alter authority",
object_reference "Object reference authority",
data_read "Data read authority",
data_add "Data add authority",
data_update "Data update authority",
data_delete "Data delete authority",
data_execute "Data execute authority",
text_description "Description"
from qsys2.object_privileges
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}'`;
}
return sql;
}

0 comments on commit 9e435e8

Please sign in to comment.