This repository has been archived by the owner on Jan 6, 2025. It is now read-only.
forked from schemaspy/schemaspy
-
Notifications
You must be signed in to change notification settings - Fork 1
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
* This works with 2017 and 2019 * Hopefully queries work with Azure * fixes schemaspy#640
- Loading branch information
Showing
8 changed files
with
79 additions
and
10 deletions.
There are no files selected for viewing
31 changes: 31 additions & 0 deletions
31
src/main/resources/org/schemaspy/types/mssql17-jtds.properties
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,31 @@ | ||
# | ||
# Copyright (C) 2020 Nils Petzaell | ||
# | ||
# This file is part of SchemaSpy. | ||
# | ||
# SchemaSpy is free software: you can redistribute it and/or modify | ||
# it under the terms of the GNU Lesser General Public License as published by | ||
# the Free Software Foundation, either version 3 of the License, or | ||
# (at your option) any later version. | ||
# | ||
# SchemaSpy is distributed in the hope that it will be useful, | ||
# but WITHOUT ANY WARRANTY; without even the implied warranty of | ||
# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the | ||
# GNU Lesser General Public License for more details. | ||
# | ||
# You should have received a copy of the GNU Lesser General Public License | ||
# along with SchemaSpy. If not, see <http://www.gnu.org/licenses/>. | ||
# | ||
extends=mssql08-jtds | ||
|
||
selectViewSql=select sm.definition as view_definition from sys.objects so left join sys.sql_modules sm on so.object_id = sm.object_id where so.[type] = 'V' and so.name =:table | ||
selectCheckConstraintsSql=select OBJECT_NAME(parent_object_id) as table_name, name AS constraint_name, definition as text from sys.check_constraints | ||
|
||
selectCatalogsSql=SELECT cast(value as nvarchar(max)) as catalog_comment FROM fn_listextendedproperty(N'MS_Description', default, default, default, default, default, default) | ||
selectSchemasSql=SELECT cast(value as nvarchar(max)) as schema_comment FROM fn_listextendedproperty(N'MS_Description', N'schema', :schema, default, default, default, default) | ||
selectTableCommentsSql=SELECT objname as table_name, cast(value as nvarchar(max)) as comments FROM fn_listextendedproperty(N'MS_Description', N'schema', :schema, 'table', null, default, default) | ||
selectColumnCommentsSql=select x.table_name, x.column_name, x.comments from ( select t.name as table_name, c.name as column_name, cast((SELECT value from fn_listextendedproperty(N'MS_Description', N'schema', SCHEMA_NAME(t.schema_id), 'table', t.name, 'column', c.name)) as NVARCHAR(MAX)) as comments from sys.tables t left join sys.columns c on (t.object_id = c.object_id) where SCHEMA_NAME(t.schema_id) = :schema ) x where not x.comments is null | ||
selectViewCommentsSql=SELECT objname as view_name, cast(value as nvarchar(max)) as comments FROM fn_listextendedproperty(N'MS_Description', N'schema', :schema, 'view', null, default, default) | ||
selectViewColumnCommentsSql=select x.view_name, x.column_name, x.comments from ( select v.name as view_name, c.name as column_name, cast((SELECT value from fn_listextendedproperty(N'MS_Description', N'schema', SCHEMA_NAME(v.schema_id), 'view', v.name, 'column', c.name)) as NVARCHAR(MAX)) as comments from sys.views v left join sys.columns c on (v.object_id = c.object_id) where SCHEMA_NAME(v.schema_id) = :schema ) x where not x.comments is null | ||
|
||
selectRoutinesSql=SELECT i_s.routine_name, i_s.routine_type, i_s.data_type AS dtd_identifier, i_s.routine_body, i_s.routine_definition, i_s.is_deterministic, i_s.sql_data_access, NULL AS security_type, NULL AS sql_mode, (select cast(value as nvarchar(max)) from fn_listextendedproperty(N'MS_Description', N'schema', i_s.routine_schema, 'procedure', i_s.ROUTINE_NAME, default, default)) AS routine_comment FROM information_schema.routines i_s WHERE routine_schema = :schema |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,31 @@ | ||
# | ||
# Copyright (C) 2020 Nils Petzaell | ||
# | ||
# This file is part of SchemaSpy. | ||
# | ||
# SchemaSpy is free software: you can redistribute it and/or modify | ||
# it under the terms of the GNU Lesser General Public License as published by | ||
# the Free Software Foundation, either version 3 of the License, or | ||
# (at your option) any later version. | ||
# | ||
# SchemaSpy is distributed in the hope that it will be useful, | ||
# but WITHOUT ANY WARRANTY; without even the implied warranty of | ||
# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the | ||
# GNU Lesser General Public License for more details. | ||
# | ||
# You should have received a copy of the GNU Lesser General Public License | ||
# along with SchemaSpy. If not, see <http://www.gnu.org/licenses/>. | ||
# | ||
extends=mssql08 | ||
|
||
selectViewSql=select sm.definition as view_definition from sys.objects so left join sys.sql_modules sm on so.object_id = sm.object_id where so.[type] = 'V' and so.name =:table | ||
selectCheckConstraintsSql=select OBJECT_NAME(parent_object_id) as table_name, name AS constraint_name, definition as text from sys.check_constraints | ||
|
||
selectCatalogsSql=SELECT cast(value as nvarchar(max)) as catalog_comment FROM fn_listextendedproperty(N'MS_Description', default, default, default, default, default, default) | ||
selectSchemasSql=SELECT cast(value as nvarchar(max)) as schema_comment FROM fn_listextendedproperty(N'MS_Description', N'schema', :schema, default, default, default, default) | ||
selectTableCommentsSql=SELECT objname as table_name, cast(value as nvarchar(max)) as comments FROM fn_listextendedproperty(N'MS_Description', N'schema', :schema, 'table', null, default, default) | ||
selectColumnCommentsSql=select x.table_name, x.column_name, x.comments from ( select t.name as table_name, c.name as column_name, cast((SELECT value from fn_listextendedproperty(N'MS_Description', N'schema', SCHEMA_NAME(t.schema_id), 'table', t.name, 'column', c.name)) as NVARCHAR(MAX)) as comments from sys.tables t left join sys.columns c on (t.object_id = c.object_id) where SCHEMA_NAME(t.schema_id) = :schema ) x where not x.comments is null | ||
selectViewCommentsSql=SELECT objname as view_name, cast(value as nvarchar(max)) as comments FROM fn_listextendedproperty(N'MS_Description', N'schema', :schema, 'view', null, default, default) | ||
selectViewColumnCommentsSql=select x.view_name, x.column_name, x.comments from ( select v.name as view_name, c.name as column_name, cast((SELECT value from fn_listextendedproperty(N'MS_Description', N'schema', SCHEMA_NAME(v.schema_id), 'view', v.name, 'column', c.name)) as NVARCHAR(MAX)) as comments from sys.views v left join sys.columns c on (v.object_id = c.object_id) where SCHEMA_NAME(v.schema_id) = :schema ) x where not x.comments is null | ||
|
||
selectRoutinesSql=SELECT i_s.routine_name, i_s.routine_type, i_s.data_type AS dtd_identifier, i_s.routine_body, i_s.routine_definition, i_s.is_deterministic, i_s.sql_data_access, NULL AS security_type, NULL AS sql_mode, (select cast(value as nvarchar(max)) from fn_listextendedproperty(N'MS_Description', N'schema', i_s.routine_schema, 'procedure', i_s.ROUTINE_NAME, default, default)) AS routine_comment FROM information_schema.routines i_s WHERE routine_schema = :schema |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1 +1,2 @@ | ||
microsoft/mssql-server-linux:2017-CU6 | ||
microsoft/mssql-server-linux:2017-CU6 | ||
mcr.microsoft.com/mssql/server:2019-CU3-ubuntu-16.04 |