Skip to content

Commit

Permalink
mssql QoL changes and a major bug fix (#1399)
Browse files Browse the repository at this point in the history
* Make database optional

* Use database specific information_schema

This fixes an issue with sidebar where users can't see database tables/views

* Return empty list when schema isn't accessible

This resolves 'sqltools.getChildrenForTreeItem' failed error when clicking on an inaccessible schema.
  • Loading branch information
fzhem authored Nov 28, 2024
1 parent 114957f commit 0b58466
Show file tree
Hide file tree
Showing 3 changed files with 20 additions and 14 deletions.
2 changes: 0 additions & 2 deletions packages/driver.mssql/connection.schema.json
Original file line number Diff line number Diff line change
Expand Up @@ -121,7 +121,6 @@
"required": [
"server",
"port",
"database",
"username"
]
},
Expand Down Expand Up @@ -149,7 +148,6 @@
},
"required": [
"socketPath",
"database",
"username"
]
},
Expand Down
10 changes: 9 additions & 1 deletion packages/driver.mssql/src/ls/driver.ts
Original file line number Diff line number Diff line change
Expand Up @@ -157,7 +157,15 @@ export default class MSSQL extends AbstractDriver<MSSQLLib.ConnectionPool, any>
private async getChildrenForGroup({ parent, item }: Arg0<IConnectionDriver['getChildrenForItem']>) {
switch (item.childType) {
case ContextValue.SCHEMA:
return this.queryResults(this.queries.fetchSchemas(parent as NSDatabase.IDatabase));
try {
const result = await this.queryResults(
this.queries.fetchSchemas(parent as NSDatabase.IDatabase)
);
return result;
} catch (error) {
this.close();
return [];
}
case ContextValue.TABLE:
return this.queryResults(this.queries.fetchTables(parent as NSDatabase.ISchema));
case ContextValue.VIEW:
Expand Down
22 changes: 11 additions & 11 deletions packages/driver.mssql/src/ls/queries.ts
Original file line number Diff line number Diff line change
Expand Up @@ -34,20 +34,20 @@ SELECT
(CASE WHEN LOWER(TC.CONSTRAINT_TYPE) = 'primary key' THEN 1 ELSE 0 END) as "isPk",
(CASE WHEN LOWER(TC.CONSTRAINT_TYPE) = 'foreign key' THEN 1 ELSE 0 END) as "isFk"
FROM
INFORMATION_SCHEMA.COLUMNS C
LEFT JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE AS KCU ON (
${p => p.database ? `${escapeTableName({ database: p.database, schema: "INFORMATION_SCHEMA", label: "COLUMNS" })}` : 'INFORMATION_SCHEMA.COLUMNS'} C
LEFT JOIN ${p => p.database ? `${escapeTableName({ database: p.database, schema: "INFORMATION_SCHEMA", label: "KEY_COLUMN_USAGE" })}` : 'INFORMATION_SCHEMA.KEY_COLUMN_USAGE'} AS KCU ON (
C.TABLE_CATALOG = KCU.TABLE_CATALOG
AND C.TABLE_NAME = KCU.TABLE_NAME
AND C.TABLE_SCHEMA = KCU.TABLE_SCHEMA
AND C.TABLE_CATALOG = KCU.TABLE_CATALOG
AND C.COLUMN_NAME = KCU.COLUMN_NAME
)
LEFT JOIN INFORMATION_SCHEMA.TABLE_CONSTRAINTS AS TC ON (
LEFT JOIN ${p => p.database ? `${escapeTableName({ database: p.database, schema: "INFORMATION_SCHEMA", label: "TABLE_CONSTRAINTS" })}` : 'INFORMATION_SCHEMA.TABLE_CONSTRAINTS'} AS TC ON (
TC.CONSTRAINT_NAME = KCU.CONSTRAINT_NAME
AND TC.TABLE_SCHEMA = KCU.TABLE_SCHEMA
AND TC.TABLE_CATALOG = KCU.TABLE_CATALOG
)
JOIN INFORMATION_SCHEMA.TABLES AS T ON C.TABLE_NAME = T.TABLE_NAME
JOIN ${p => p.database ? `${escapeTableName({ database: p.database, schema: "INFORMATION_SCHEMA", label: "TABLES" })}` : 'INFORMATION_SCHEMA.TABLES'} AS T ON C.TABLE_NAME = T.TABLE_NAME
AND C.TABLE_SCHEMA = T.TABLE_SCHEMA
AND C.TABLE_CATALOG = T.TABLE_CATALOG
WHERE
Expand Down Expand Up @@ -79,7 +79,7 @@ SELECT
T.TABLE_SCHEMA AS "schema",
T.TABLE_CATALOG AS "database",
CONVERT(BIT, CASE WHEN T.TABLE_TYPE = 'BASE TABLE' THEN 0 ELSE 1 END) AS "isView"
FROM INFORMATION_SCHEMA.TABLES AS T
FROM ${p => p.database ? `${escapeTableName({ database: p.database, schema: "INFORMATION_SCHEMA", label: "TABLES" })}` : 'INFORMATION_SCHEMA.TABLES'} AS T
WHERE
T.TABLE_SCHEMA = '${p => p.schema}'
AND T.TABLE_CATALOG = '${p => p.database}'
Expand All @@ -98,7 +98,7 @@ SELECT
'${ContextValue.SCHEMA}' as "type",
'group-by-ref-type' as "iconId",
catalog_name as "database"
FROM information_schema.schemata
FROM ${p => p.database ? `${escapeTableName({ database: p.database, schema: "information_schema", label: "schemata" })}` : 'information_schema.schemata'}
WHERE
LOWER(schema_name) NOT IN ('information_schema', 'sys', 'guest')
AND LOWER(schema_name) NOT LIKE 'db\\_%' ESCAPE '\\'
Expand All @@ -123,7 +123,7 @@ SELECT
(CASE WHEN T.TABLE_TYPE = 'BASE TABLE' THEN 0 ELSE 1 END) AS "isView",
(CASE WHEN T.TABLE_TYPE = 'BASE TABLE' THEN 'table' ELSE 'view' END) AS description,
('[' + T.TABLE_CATALOG + '].[' + T.TABLE_SCHEMA + '].[' + T.TABLE_NAME + ']') as detail
FROM INFORMATION_SCHEMA.TABLES AS T
FROM ${p => p.database ? `${escapeTableName({ database: p.database, schema: "INFORMATION_SCHEMA", label: "TABLES" })}` : 'INFORMATION_SCHEMA.TABLES'} AS T
WHERE
LOWER(T.TABLE_SCHEMA) NOT IN ('information_schema', 'sys', 'guest')
AND LOWER(T.TABLE_SCHEMA) NOT LIKE 'db\\_%' ESCAPE '\\'
Expand Down Expand Up @@ -152,20 +152,20 @@ SELECT
(CASE WHEN LOWER(TC.CONSTRAINT_TYPE) = 'primary key' THEN 1 ELSE 0 END) as "isPk",
(CASE WHEN LOWER(TC.CONSTRAINT_TYPE) = 'foreign key' THEN 1 ELSE 0 END) as "isFk"
FROM
INFORMATION_SCHEMA.COLUMNS C
LEFT JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE AS KCU ON (
${p => p.tables[0].database ? `${escapeTableName({ database: p.tables[0].database, schema: "INFORMATION_SCHEMA", label: "COLUMNS" })}` : 'INFORMATION_SCHEMA.COLUMNS'} C
LEFT JOIN ${p => p.tables[0].database ? `${escapeTableName({ database: p.tables[0].database, schema: "INFORMATION_SCHEMA", label: "KEY_COLUMN_USAGE" })}` : 'INFORMATION_SCHEMA.KEY_COLUMN_USAGE'} AS KCU ON (
C.TABLE_CATALOG = KCU.TABLE_CATALOG
AND C.TABLE_NAME = KCU.TABLE_NAME
AND C.TABLE_SCHEMA = KCU.TABLE_SCHEMA
AND C.TABLE_CATALOG = KCU.TABLE_CATALOG
AND C.COLUMN_NAME = KCU.COLUMN_NAME
)
LEFT JOIN INFORMATION_SCHEMA.TABLE_CONSTRAINTS AS TC ON (
LEFT JOIN ${p => p.tables[0].database ? `${escapeTableName({ database: p.tables[0].database, schema: "INFORMATION_SCHEMA", label: "TABLE_CONSTRAINTS" })}` : 'INFORMATION_SCHEMA.TABLE_CONSTRAINTS'} AS TC ON (
TC.CONSTRAINT_NAME = KCU.CONSTRAINT_NAME
AND TC.TABLE_SCHEMA = KCU.TABLE_SCHEMA
AND TC.TABLE_CATALOG = KCU.TABLE_CATALOG
)
JOIN INFORMATION_SCHEMA.TABLES AS T ON C.TABLE_NAME = T.TABLE_NAME
JOIN ${p => p.tables[0].database ? `${escapeTableName({ database: p.tables[0].database, schema: "INFORMATION_SCHEMA", label: "TABLES" })}` : 'INFORMATION_SCHEMA.TABLES'} AS T ON C.TABLE_NAME = T.TABLE_NAME
AND C.TABLE_SCHEMA = T.TABLE_SCHEMA
AND C.TABLE_CATALOG = T.TABLE_CATALOG
WHERE LOWER(C.TABLE_SCHEMA) NOT IN ('information_schema', 'sys', 'guest')
Expand Down

0 comments on commit 0b58466

Please sign in to comment.