├── images
├── backup2.gif
├── command.gif
└── select.gif
├── SqlTelegram
├── Assemblies
│ ├── SqlTelegram.dll
│ ├── Accessibility.dll
│ ├── SMDiagnostics.dll
│ ├── System.Drawing.dll
│ ├── Newtonsoft.Json.dll
│ ├── SMDiagnostics_1.dll
│ ├── System.Messaging.dll
│ ├── System.Windows.Forms.dll
│ ├── System.DirectoryServices.dll
│ ├── System_1.Windows.Forms.dll
│ ├── System.Configuration.Install.dll
│ ├── System.Runtime.Serialization.dll
│ ├── System.ServiceModel.Internals.dll
│ ├── System_1.Runtime.Serialization.dll
│ ├── System_1.ServiceModel.Internals.dll
│ └── System.Runtime.Serialization.Formatters.Soap.dll
├── dbo
│ ├── Functions
│ │ ├── ufn_get_num_cols.sql
│ │ ├── ufn_get_num_cols_1.sql
│ │ ├── ufn_get_num_rows.sql
│ │ ├── ufn_get_num_rows_1.sql
│ │ ├── ufn_get_col_width.sql
│ │ ├── ufn_get_col_width_1.sql
│ │ ├── ufn_get_last_update_id.sql
│ │ └── ufn_get_last_update_id_1.sql
│ ├── Stored Procedures
│ │ ├── usp_remove_user.sql
│ │ ├── usp_HttpGet.sql
│ │ ├── usp_Message2Command.sql
│ │ ├── usp_SQL2string.sql
│ │ ├── usp_HttpPost.sql
│ │ ├── usp_add_user.sql
│ │ ├── usp_get_bot_name.sql
│ │ ├── usp_SendSticker.sql
│ │ ├── usp_SendMessage.sql
│ │ ├── usp_GetChatId.sql
│ │ ├── usp_get_settings.sql
│ │ ├── usp_request_access.sql
│ │ └── usp_get_chat_updates.sql
│ └── Tables
│ │ ├── users.sql
│ │ ├── settings.sql
│ │ └── commands.sql
├── Security
│ └── monitor.sql
├── monitor
│ ├── Tables
│ │ ├── threshold.sql
│ │ ├── progress.sql
│ │ └── disk_latency.sql
│ └── Stored Procedures
│ │ ├── usp_check_cpu_usage.sql
│ │ ├── usp_check_lock_wait.sql
│ │ ├── usp_check_disk_free_space.sql
│ │ ├── usp_get_job_execution_stats.sql
│ │ ├── usp_check_job_failed.sql
│ │ ├── usp_get_top_queries.sql
│ │ ├── usp_check_disk_latency.sql
│ │ └── usp_get_progress.sql
├── CLR
│ ├── HttpResult.cs
│ ├── HttpLayer.cs
│ └── ClrHttp.cs
└── SqlTelegram.sqlproj
├── SqlTelegram.sln
├── README.md
├── Configure.sql
├── .gitignore
├── Jobs.sql
└── LICENSE
/images/backup2.gif:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/images/backup2.gif
--------------------------------------------------------------------------------
/images/command.gif:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/images/command.gif
--------------------------------------------------------------------------------
/images/select.gif:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/images/select.gif
--------------------------------------------------------------------------------
/SqlTelegram/Assemblies/SqlTelegram.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/SqlTelegram/Assemblies/SqlTelegram.dll
--------------------------------------------------------------------------------
/SqlTelegram/Assemblies/Accessibility.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/SqlTelegram/Assemblies/Accessibility.dll
--------------------------------------------------------------------------------
/SqlTelegram/Assemblies/SMDiagnostics.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/SqlTelegram/Assemblies/SMDiagnostics.dll
--------------------------------------------------------------------------------
/SqlTelegram/Assemblies/System.Drawing.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/SqlTelegram/Assemblies/System.Drawing.dll
--------------------------------------------------------------------------------
/SqlTelegram/Assemblies/Newtonsoft.Json.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/SqlTelegram/Assemblies/Newtonsoft.Json.dll
--------------------------------------------------------------------------------
/SqlTelegram/Assemblies/SMDiagnostics_1.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/SqlTelegram/Assemblies/SMDiagnostics_1.dll
--------------------------------------------------------------------------------
/SqlTelegram/Assemblies/System.Messaging.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/SqlTelegram/Assemblies/System.Messaging.dll
--------------------------------------------------------------------------------
/SqlTelegram/Assemblies/System.Windows.Forms.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/SqlTelegram/Assemblies/System.Windows.Forms.dll
--------------------------------------------------------------------------------
/SqlTelegram/Assemblies/System.DirectoryServices.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/SqlTelegram/Assemblies/System.DirectoryServices.dll
--------------------------------------------------------------------------------
/SqlTelegram/Assemblies/System_1.Windows.Forms.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/SqlTelegram/Assemblies/System_1.Windows.Forms.dll
--------------------------------------------------------------------------------
/SqlTelegram/Assemblies/System.Configuration.Install.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/SqlTelegram/Assemblies/System.Configuration.Install.dll
--------------------------------------------------------------------------------
/SqlTelegram/Assemblies/System.Runtime.Serialization.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/SqlTelegram/Assemblies/System.Runtime.Serialization.dll
--------------------------------------------------------------------------------
/SqlTelegram/Assemblies/System.ServiceModel.Internals.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/SqlTelegram/Assemblies/System.ServiceModel.Internals.dll
--------------------------------------------------------------------------------
/SqlTelegram/Assemblies/System_1.Runtime.Serialization.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/SqlTelegram/Assemblies/System_1.Runtime.Serialization.dll
--------------------------------------------------------------------------------
/SqlTelegram/Assemblies/System_1.ServiceModel.Internals.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/SqlTelegram/Assemblies/System_1.ServiceModel.Internals.dll
--------------------------------------------------------------------------------
/SqlTelegram/Assemblies/System.Runtime.Serialization.Formatters.Soap.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/gleberof/SQL-telegram-bot/HEAD/SqlTelegram/Assemblies/System.Runtime.Serialization.Formatters.Soap.dll
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Functions/ufn_get_num_cols.sql:
--------------------------------------------------------------------------------
1 |
2 | CREATE FUNCTION [dbo].[ufn_get_num_cols]()
3 | RETURNS bigint
4 | AS
5 | BEGIN
6 | RETURN (SELECT [value] FROM [dbo].[settings] WHERE [name] = N'num_cols');
7 | END
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Functions/ufn_get_num_cols_1.sql:
--------------------------------------------------------------------------------
1 |
2 | CREATE FUNCTION [dbo].[ufn_get_num_cols]()
3 | RETURNS bigint
4 | AS
5 | BEGIN
6 | RETURN (SELECT [value] FROM [dbo].[settings] WHERE [name] = N'num_cols');
7 | END
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Functions/ufn_get_num_rows.sql:
--------------------------------------------------------------------------------
1 |
2 | CREATE FUNCTION [dbo].[ufn_get_num_rows]()
3 | RETURNS bigint
4 | AS
5 | BEGIN
6 | RETURN (SELECT [value] FROM [dbo].[settings] WHERE [name] = N'num_rows');
7 | END
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Functions/ufn_get_num_rows_1.sql:
--------------------------------------------------------------------------------
1 |
2 | CREATE FUNCTION [dbo].[ufn_get_num_rows]()
3 | RETURNS bigint
4 | AS
5 | BEGIN
6 | RETURN (SELECT [value] FROM [dbo].[settings] WHERE [name] = N'num_rows');
7 | END
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Functions/ufn_get_col_width.sql:
--------------------------------------------------------------------------------
1 |
2 | CREATE FUNCTION [dbo].[ufn_get_col_width]()
3 | RETURNS bigint
4 | AS
5 | BEGIN
6 | RETURN (SELECT [value] FROM [dbo].[settings] WHERE [name] = N'col_width');
7 | END
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Functions/ufn_get_col_width_1.sql:
--------------------------------------------------------------------------------
1 |
2 | CREATE FUNCTION [dbo].[ufn_get_col_width]()
3 | RETURNS bigint
4 | AS
5 | BEGIN
6 | RETURN (SELECT [value] FROM [dbo].[settings] WHERE [name] = N'col_width');
7 | END
--------------------------------------------------------------------------------
/SqlTelegram/Security/monitor.sql:
--------------------------------------------------------------------------------
1 | CREATE SCHEMA [monitor]
2 | AUTHORIZATION [dbo];
3 |
4 |
5 |
6 |
7 |
8 |
9 |
10 |
11 |
12 |
13 |
14 |
15 |
16 |
17 |
18 |
19 |
20 |
21 |
22 |
23 |
24 |
25 |
26 |
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Functions/ufn_get_last_update_id.sql:
--------------------------------------------------------------------------------
1 |
2 | CREATE FUNCTION [dbo].[ufn_get_last_update_id]()
3 | RETURNS bigint
4 | AS
5 | BEGIN
6 | RETURN (SELECT [value] FROM [dbo].[settings] WHERE [name] = N'last_update_id');
7 | END
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Functions/ufn_get_last_update_id_1.sql:
--------------------------------------------------------------------------------
1 |
2 | CREATE FUNCTION [dbo].[ufn_get_last_update_id]()
3 | RETURNS bigint
4 | AS
5 | BEGIN
6 | RETURN (SELECT [value] FROM [dbo].[settings] WHERE [name] = N'last_update_id');
7 | END
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Stored Procedures/usp_remove_user.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [dbo].[usp_remove_user]
2 | (
3 | @user_id bigint
4 | )
5 | AS
6 | BEGIN
7 | SET NOCOUNT ON;
8 |
9 | DELETE [dbo].[users]
10 | WHERE [user_id] = @user_id;
11 |
12 | END
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Tables/users.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [dbo].[users] (
2 | [user_id] BIGINT NOT NULL,
3 | [name] NCHAR (50) NOT NULL,
4 | [authorized] BIT NOT NULL,
5 | CONSTRAINT [PK_users] PRIMARY KEY CLUSTERED ([user_id] ASC)
6 | );
7 |
8 |
--------------------------------------------------------------------------------
/SqlTelegram/monitor/Tables/threshold.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [monitor].[threshold] (
2 | [counter] NVARCHAR (255) NOT NULL,
3 | [threshold] DECIMAL (18, 2) NOT NULL,
4 | [type] NVARCHAR (10) NOT NULL,
5 | CONSTRAINT [PK_threshold] PRIMARY KEY CLUSTERED ([counter] ASC)
6 | );
7 |
8 |
9 |
10 |
--------------------------------------------------------------------------------
/SqlTelegram/CLR/HttpResult.cs:
--------------------------------------------------------------------------------
1 | namespace SqlTelegram
2 | {
3 | public class HttpResult
4 | {
5 | public bool Success { get; set; }
6 |
7 | public string Response { get; set; }
8 |
9 | public string ErrorMessage { get; set; }
10 |
11 | public string Error { get; set; }
12 | }
13 | }
14 |
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Stored Procedures/usp_HttpGet.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [dbo].[usp_HttpGet]
2 | @url NVARCHAR (MAX) NULL, @headerXml XML NULL, @success BIT NULL OUTPUT, @response NVARCHAR (MAX) NULL OUTPUT, @error NVARCHAR (MAX) NULL OUTPUT
3 | AS EXTERNAL NAME [SqlTelegram].[SqlTelegram.ClrHttp].[HttpGet]
4 |
5 |
6 |
7 |
8 |
9 |
10 |
11 |
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Stored Procedures/usp_Message2Command.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [dbo].[usp_Message2Command]
2 | @json NVARCHAR (MAX) NULL, @bot_name NVARCHAR (MAX) NULL, @chat_id NVARCHAR (MAX) NULL, @response NVARCHAR (MAX) NULL OUTPUT
3 | AS EXTERNAL NAME [SqlTelegram].[SqlTelegram.ClrHttp].[Message2Command]
4 |
5 |
6 |
7 |
8 |
9 |
10 |
11 |
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Tables/settings.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [dbo].[settings] (
2 | [name] NVARCHAR (50) NOT NULL,
3 | [value] BIGINT NULL,
4 | [value_str] NVARCHAR (MAX) NULL,
5 | [value_date] DATETIME NULL,
6 | CONSTRAINT [PK_settings] PRIMARY KEY CLUSTERED ([name] ASC)
7 | );
8 |
9 |
10 |
11 |
12 |
13 |
14 |
15 |
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Stored Procedures/usp_SQL2string.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [dbo].[usp_SQL2string]
2 | @SqlString NVARCHAR (MAX) NULL, @num_rows INT NULL, @num_cols INT NULL, @col_width INT NULL, @list_width NVARCHAR (MAX) NULL, @response NVARCHAR (MAX) NULL OUTPUT
3 | AS EXTERNAL NAME [SqlTelegram].[SqlTelegram.ClrHttp].[SQL2string]
4 |
5 |
6 |
7 |
8 |
9 |
10 |
11 |
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Stored Procedures/usp_HttpPost.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [dbo].[usp_HttpPost]
2 | @url NVARCHAR (MAX) NULL, @headerXml XML NULL, @requestBody NVARCHAR (MAX) NULL, @success BIT NULL OUTPUT, @response NVARCHAR (MAX) NULL OUTPUT, @error NVARCHAR (MAX) NULL OUTPUT
3 | AS EXTERNAL NAME [SqlTelegram].[SqlTelegram.ClrHttp].[HttpPost]
4 |
5 |
6 |
7 |
8 |
9 |
10 |
11 |
--------------------------------------------------------------------------------
/SqlTelegram/monitor/Tables/progress.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [monitor].[progress] (
2 | [session_id] BIGINT NOT NULL,
3 | [message_id] BIGINT NOT NULL,
4 | [command] NVARCHAR (50) NOT NULL,
5 | [database] [sysname] NULL,
6 | [start_time] DATETIME NULL,
7 | [estimated_completion_time] DATETIME NULL,
8 | PRIMARY KEY CLUSTERED ([session_id] ASC)
9 | );
10 |
11 |
--------------------------------------------------------------------------------
/SqlTelegram/monitor/Tables/disk_latency.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [monitor].[disk_latency] (
2 | [database_id] SMALLINT NOT NULL,
3 | [file_id] SMALLINT NOT NULL,
4 | [sample_ms] BIGINT NULL,
5 | [num_of_reads] BIGINT NULL,
6 | [num_of_writes] BIGINT NULL,
7 | [io_stall_read_ms] BIGINT NULL,
8 | [io_stall_write_ms] BIGINT NULL,
9 | CONSTRAINT [PK_disk_latency] PRIMARY KEY CLUSTERED ([database_id] ASC, [file_id] ASC)
10 | );
11 |
12 |
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Stored Procedures/usp_add_user.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [dbo].[usp_add_user]
2 | (
3 | @user_id bigint
4 | ,@name nvarchar(50)
5 | ,@authorized bit
6 | )
7 | AS
8 | BEGIN
9 | SET NOCOUNT ON;
10 |
11 | IF NOT EXISTS
12 | (
13 | SELECT 1
14 | FROM [dbo].[users]
15 | WHERE [user_id] = @user_id
16 | )
17 | INSERT INTO [dbo].[users]
18 | (
19 | [user_id]
20 | ,[name]
21 | ,[authorized]
22 | )
23 | VALUES
24 | (
25 | @user_id
26 | ,@name
27 | ,@authorized
28 | );
29 |
30 | END
--------------------------------------------------------------------------------
/SqlTelegram/monitor/Stored Procedures/usp_check_cpu_usage.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [monitor].[usp_check_cpu_usage]
2 | AS
3 | BEGIN
4 | SET NOCOUNT ON ;
5 |
6 | DECLARE
7 | @message nvarchar(max)
8 | ,@threshold int
9 | ,@cpu_value int;
10 |
11 | SELECT @threshold = [t].[threshold]
12 | FROM [monitor].[threshold] [t]
13 | WHERE [t].[counter] = N'cpu_usage';
14 |
15 | SELECT
16 | @cpu_value = [record].value('(./Record/SchedulerMonitorEvent/SystemHealth/ProcessUtilization)[1]', 'int')
17 | FROM
18 | (
19 | SELECT TOP (1) CONVERT(XML, [record]) AS [record]
20 | FROM sys.dm_os_ring_buffers [rb]
21 | WHERE [ring_buffer_type] = N'RING_BUFFER_SCHEDULER_MONITOR'
22 | AND [record] LIKE '% %'
23 | ORDER BY [timestamp] DESC
24 | ) AS [cpu_usage];
25 |
26 | IF @cpu_value >= @threshold
27 | BEGIN
28 | SET @message = N'Загрузка CPU: ' + CAST(@cpu_value AS nvarchar(3)) + '%';
29 |
30 | EXEC [dbo].[usp_SendMessage]
31 | @message = @message;
32 | END;
33 |
34 | END;
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Stored Procedures/usp_get_bot_name.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [dbo].[usp_get_bot_name]
2 | (
3 | @bot_name nvarchar(max) OUTPUT
4 | )
5 | AS
6 | BEGIN
7 | SET NOCOUNT ON;
8 |
9 | DECLARE
10 | @url nvarchar(max)
11 | ,@http_headers xml
12 | ,@json_chat nvarchar(max) = '{}'
13 | ,@message_url nvarchar(max)
14 | ,@success bit
15 | ,@response nvarchar(max)
16 | ,@error nvarchar(max);
17 |
18 | EXEC [dbo].[usp_get_settings]
19 | @url = @url OUTPUT
20 | ,@http_headers = @http_headers OUTPUT;
21 |
22 | SET @message_url = CONCAT(@url, 'getMe');
23 |
24 | EXEC [dbo].[usp_HttpPost]
25 | @url = @message_url,
26 | @headerXml = @http_headers,
27 | @requestBody = @json_chat,
28 | @success = @success OUTPUT,
29 | @response = @response OUTPUT,
30 | @error = @error OUTPUT;
31 |
32 | SELECT TOP (1) @bot_name = [username]
33 | FROM OPENJSON (@response, N'$.result')
34 | WITH
35 | (
36 | [username] nvarchar(max) N'$.username'
37 | );
38 |
39 | END;
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Stored Procedures/usp_SendSticker.sql:
--------------------------------------------------------------------------------
1 |
2 | CREATE PROCEDURE [dbo].[usp_SendSticker]
3 | (
4 | @sticker nvarchar(max)
5 | )
6 | AS
7 | BEGIN
8 | SET NOCOUNT ON;
9 |
10 | DECLARE
11 | @chat_id bigint
12 | ,@url nvarchar(max)
13 | ,@http_headers xml
14 | ,@json_chat nvarchar(max) = N'{}'
15 | ,@message_url nvarchar(max)
16 | ,@success bit
17 | ,@response nvarchar(max)
18 | ,@error nvarchar(max);
19 |
20 | EXEC [dbo].[usp_get_settings]
21 | @url = @url OUTPUT
22 | ,@http_headers = @http_headers OUTPUT
23 | ,@chat_id = @chat_id OUTPUT;
24 |
25 | SET @message_url = CONCAT(@url, N'sendSticker');
26 | SET @json_chat = JSON_MODIFY(@json_chat, '$.sticker', @sticker);
27 | SET @json_chat = JSON_MODIFY(@json_chat, '$.chat_id', @chat_id);
28 |
29 | EXEC dbo.usp_HttpPost
30 | @url = @message_url,
31 | @headerXml = @http_headers,
32 | @requestBody = @json_chat,
33 | @success = @success OUTPUT,
34 | @response = @response OUTPUT,
35 | @error = @error OUTPUT;
36 | END
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Stored Procedures/usp_SendMessage.sql:
--------------------------------------------------------------------------------
1 |
2 | CREATE PROCEDURE [dbo].[usp_SendMessage]
3 | (
4 | @message nvarchar(max)
5 | )
6 | AS
7 | BEGIN
8 | SET NOCOUNT ON;
9 |
10 | DECLARE
11 | @chat_id bigint
12 | ,@url nvarchar(max)
13 | ,@http_headers xml
14 | ,@json_chat nvarchar(max) = N'{}'
15 | ,@message_url nvarchar(max)
16 | ,@success bit
17 | ,@response nvarchar(max)
18 | ,@error nvarchar(max);
19 |
20 | EXEC [dbo].[usp_get_settings]
21 | @url = @url OUTPUT
22 | ,@http_headers = @http_headers OUTPUT
23 | ,@chat_id = @chat_id OUTPUT;
24 |
25 | SET @message_url = CONCAT(@url, N'sendMessage');
26 | SET @json_chat = JSON_MODIFY(@json_chat, '$.text', @message);
27 | SET @json_chat = JSON_MODIFY(@json_chat, '$.chat_id', @chat_id);
28 |
29 | EXEC [dbo].[usp_HttpPost]
30 | @url = @message_url,
31 | @headerXml = @http_headers,
32 | @requestBody = @json_chat,
33 | @success = @success OUTPUT,
34 | @response = @response OUTPUT,
35 | @error = @error OUTPUT;
36 |
37 | END
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Stored Procedures/usp_GetChatId.sql:
--------------------------------------------------------------------------------
1 |
2 | CREATE PROCEDURE [dbo].[usp_GetChatId]
3 | (
4 | @chat_id bigint OUTPUT
5 | )
6 | AS
7 | BEGIN
8 | SET NOCOUNT ON;
9 |
10 | DECLARE
11 | @url nvarchar(max)
12 | ,@http_headers xml
13 | ,@json_chat nvarchar(max) = '{}'
14 | ,@message_url nvarchar(max)
15 | ,@success bit
16 | ,@response nvarchar(max)
17 | ,@error nvarchar(max);
18 |
19 | EXEC [dbo].[usp_get_settings]
20 | @url = @url OUTPUT
21 | ,@http_headers = @http_headers OUTPUT;
22 |
23 | SET @message_url = CONCAT(@url, 'getUpdates');
24 |
25 | EXEC [dbo].[usp_HttpPost]
26 | @url = @message_url,
27 | @headerXml = @http_headers,
28 | @requestBody = @json_chat,
29 | @success = @success OUTPUT,
30 | @response = @response OUTPUT,
31 | @error = @error OUTPUT;
32 |
33 | SELECT TOP (1) @chat_id = [chat_id]
34 | FROM OPENJSON (@response, N'$.result')
35 | WITH
36 | (
37 | [chat_id] nvarchar(max) N'$.message.chat.id'
38 | ,[update_id] bigint N'$.update_id'
39 | )
40 | ORDER BY [update_id] DESC;
41 |
42 | END;
--------------------------------------------------------------------------------
/SqlTelegram/monitor/Stored Procedures/usp_check_lock_wait.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [monitor].[usp_check_lock_wait]
2 | AS
3 | BEGIN
4 | SET NOCOUNT ON ;
5 |
6 | DECLARE
7 | @message nvarchar(max)
8 | ,@threshold bigint;
9 |
10 | SELECT @threshold = [t].[threshold]
11 | FROM [monitor].[threshold] [t]
12 | WHERE [t].[counter] = N'lock_wait'
13 |
14 | SELECT @message = STUFF
15 | ((
16 | SELECT CHAR(10)
17 | + N'Сессия ' + CAST([p].[spid] as nvarchar(max)) + N' заблокирована сессией ' + CAST([p].[blocked] as nvarchar(max)) + N' дольше ' + CAST([p].[waittime]/1000 as nvarchar(max)) + N' секунд' + CHAR(10)
18 | + N'Тип ожидания: ' + [p].[lastwaittype] + CHAR(10)
19 | + N'База данных: ' + DB_NAME([p].[dbid]) + CHAR(10)
20 | + N'Объект ожидания: ' + [p].[waitresource] + CHAR(10)
21 | FROM sys.sysprocesses [p]
22 | WHERE [p].[blocked] > 0
23 | AND [p].[blocked] <> [p].[spid]
24 | AND [p].[waittime] >= @threshold * 1000
25 | FOR XML PATH(N''))
26 | , 1, 1, N''
27 | );
28 |
29 | IF @message IS NOT NULL
30 | EXEC [dbo].[usp_SendMessage]
31 | @message = @message;
32 |
33 | END;
--------------------------------------------------------------------------------
/SqlTelegram/monitor/Stored Procedures/usp_check_disk_free_space.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [monitor].[usp_check_disk_free_space]
2 | AS
3 | BEGIN
4 | SET NOCOUNT ON ;
5 |
6 | DECLARE
7 | @message nvarchar(max)
8 | ,@threshold int
9 | ,@cpu_value int;
10 |
11 | SELECT @threshold = [t].[threshold]
12 | FROM [monitor].[threshold] [t]
13 | WHERE [t].[counter] = N'disk_free_space_pct';
14 |
15 | ;WITH [disk_free_space] AS
16 | (
17 | SELECT DISTINCT
18 | [disk_name] = LEFT([dovs].[volume_mount_point], 1)
19 | ,[free_space_prc] = CONVERT(decimal(5,2), CONVERT(decimal(18,2), [dovs].[available_bytes]/1048576.0)/CONVERT(decimal(18,2), [dovs].[total_bytes]/1048576.0) * 100)
20 | FROM sys.master_files [mf]
21 | CROSS APPLY sys.dm_os_volume_stats([mf].[database_id], [mf].[FILE_ID]) [dovs]
22 | )
23 | SELECT @message = STUFF
24 | ((
25 | SELECT CHAR(10)
26 | + N'Свободное место на диске ' + [disk_name] + N': ' + CAST([dfs].[free_space_prc] AS nvarchar(6)) + N'%' + CHAR(10)
27 | FROM [disk_free_space] [dfs]
28 | WHERE [dfs].[free_space_prc] <= @threshold
29 | FOR XML PATH(N''))
30 | , 1, 1, N''
31 | );
32 |
33 | IF @message IS NOT NULL
34 | EXEC [dbo].[usp_SendMessage]
35 | @message = @message;
36 |
37 | END;
--------------------------------------------------------------------------------
/SqlTelegram.sln:
--------------------------------------------------------------------------------
1 |
2 | Microsoft Visual Studio Solution File, Format Version 12.00
3 | # Visual Studio 15
4 | VisualStudioVersion = 15.0.28307.1000
5 | MinimumVisualStudioVersion = 10.0.40219.1
6 | Project("{00D1A9C2-B5F0-4AF3-8072-F6C62B433612}") = "SqlTelegram", "SqlTelegram\SqlTelegram.sqlproj", "{E493F856-7BB1-4A96-87CC-D3FF25F458F1}"
7 | EndProject
8 | Global
9 | GlobalSection(SolutionConfigurationPlatforms) = preSolution
10 | Debug|Any CPU = Debug|Any CPU
11 | Release|Any CPU = Release|Any CPU
12 | EndGlobalSection
13 | GlobalSection(ProjectConfigurationPlatforms) = postSolution
14 | {E493F856-7BB1-4A96-87CC-D3FF25F458F1}.Debug|Any CPU.ActiveCfg = Debug|Any CPU
15 | {E493F856-7BB1-4A96-87CC-D3FF25F458F1}.Debug|Any CPU.Build.0 = Debug|Any CPU
16 | {E493F856-7BB1-4A96-87CC-D3FF25F458F1}.Debug|Any CPU.Deploy.0 = Debug|Any CPU
17 | {E493F856-7BB1-4A96-87CC-D3FF25F458F1}.Release|Any CPU.ActiveCfg = Release|Any CPU
18 | {E493F856-7BB1-4A96-87CC-D3FF25F458F1}.Release|Any CPU.Build.0 = Release|Any CPU
19 | {E493F856-7BB1-4A96-87CC-D3FF25F458F1}.Release|Any CPU.Deploy.0 = Release|Any CPU
20 | EndGlobalSection
21 | GlobalSection(SolutionProperties) = preSolution
22 | HideSolutionNode = FALSE
23 | EndGlobalSection
24 | GlobalSection(ExtensibilityGlobals) = postSolution
25 | SolutionGuid = {7D1B4ACA-16BD-43FF-9682-8F9FD96A4CC6}
26 | EndGlobalSection
27 | EndGlobal
28 |
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Tables/commands.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [dbo].[commands] (
2 | [command] NVARCHAR (50) NOT NULL,
3 | [query] NVARCHAR (MAX) NOT NULL,
4 | [description] NVARCHAR (MAX) NULL,
5 | [columns_width] NVARCHAR (MAX) CONSTRAINT [df_columns_width] DEFAULT (N'') NOT NULL,
6 | CONSTRAINT [PK_commands] PRIMARY KEY CLUSTERED ([command] ASC)
7 | );
8 |
9 |
10 |
11 |
12 |
13 |
14 |
15 |
16 | GO
17 | CREATE TRIGGER [dbo].[tr_commands_change]
18 | ON [dbo].[commands]
19 | AFTER INSERT,DELETE,UPDATE
20 | AS
21 | BEGIN
22 | SET NOCOUNT ON;
23 |
24 | DECLARE
25 | @chat_id bigint
26 | ,@url nvarchar(max)
27 | ,@http_headers xml
28 | ,@json_chat nvarchar(max) = N'{}'
29 | ,@message_url nvarchar(max)
30 | ,@success bit
31 | ,@response nvarchar(max)
32 | ,@error nvarchar(max)
33 | ,@commands nvarchar(max);
34 |
35 | EXEC [dbo].[usp_get_settings]
36 | @url = @url OUTPUT
37 | ,@http_headers = @http_headers OUTPUT
38 | ,@chat_id = @chat_id OUTPUT;
39 |
40 | SET @commands =
41 | (
42 | SELECT
43 | [command] = [c].[command]
44 | ,[description] = [c].[description]
45 | FROM [dbo].[commands] [c]
46 | FOR JSON AUTO
47 | );
48 |
49 | SET @message_url = CONCAT(@url, 'setMyCommands');
50 | SET @json_chat = JSON_MODIFY(@json_chat,'$.commands', @commands);
51 |
52 | EXEC [dbo].[usp_HttpPost]
53 | @url = @message_url,
54 | @headerXml = @http_headers,
55 | @requestBody = @json_chat,
56 | @success = @success OUTPUT,
57 | @response = @response OUTPUT,
58 | @error = @error OUTPUT;
59 |
60 | END
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Stored Procedures/usp_get_settings.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [dbo].[usp_get_settings]
2 | (
3 | @url nvarchar(max) = NULL OUTPUT
4 | ,@http_headers xml = NULL OUTPUT
5 | ,@chat_id bigint = NULL OUTPUT
6 | ,@last_update_id bigint = NULL OUTPUT
7 | ,@offset bigint = NULL OUTPUT
8 | ,@update_timeout bigint = NULL OUTPUT
9 | ,@limit bigint = NULL OUTPUT
10 | ,@num_rows bigint = NULL OUTPUT
11 | ,@num_cols bigint = NULL OUTPUT
12 | ,@col_width bigint = NULL OUTPUT
13 | ,@bot_name nvarchar(max) = NULL OUTPUT
14 | )
15 | AS
16 | BEGIN
17 | SET NOCOUNT ON;
18 |
19 | SELECT
20 | @chat_id = [chat_id]
21 | ,@col_width = [col_width]
22 | ,@last_update_id = [last_update_id]
23 | ,@offset = [offset]
24 | ,@limit = [limit]
25 | ,@num_cols = [num_cols]
26 | ,@num_rows = [num_rows]
27 | ,@update_timeout = [update_timeout]
28 | FROM
29 | (
30 | SELECT
31 | [name]
32 | ,[value]
33 | FROM [dbo].[settings] [s]
34 | ) [p]
35 | PIVOT
36 | (
37 | MAX([value])
38 | FOR [name] IN
39 | (
40 | [chat_id]
41 | ,[col_width]
42 | ,[last_update_id]
43 | ,[limit]
44 | ,[num_cols]
45 | ,[num_rows]
46 | ,[offset]
47 | ,[update_timeout]
48 | )
49 | ) [pvt];
50 |
51 | SELECT
52 | @url = [bot_token]
53 | ,@http_headers = [http_headers]
54 | ,@bot_name = [bot_name]
55 | FROM
56 | (
57 | SELECT
58 | [name]
59 | ,[value_str]
60 | FROM [dbo].[settings] [s]
61 | ) [p]
62 | PIVOT
63 | (
64 | MAX([value_str])
65 | FOR [name] IN
66 | (
67 | [bot_token]
68 | ,[http_headers]
69 | ,[bot_name]
70 | )
71 | ) [pvt];
72 |
73 | END;
--------------------------------------------------------------------------------
/SqlTelegram/monitor/Stored Procedures/usp_get_job_execution_stats.sql:
--------------------------------------------------------------------------------
1 |
2 | CREATE PROCEDURE [monitor].[usp_get_job_execution_stats]
3 | (
4 | @date_from datetime = NULL
5 | ,@job_name sysname = NULL
6 | )
7 | AS
8 | BEGIN
9 |
10 | SET NOCOUNT ON;
11 |
12 | ;WITH [cte_last_job_run] AS
13 | (
14 | SELECT
15 | [jh].[job_id]
16 | ,[jh].[run_status]
17 | ,[jh].[run_date]
18 | ,[jh].[run_time]
19 | ,[jh].[run_duration]
20 | ,[rn] = RANK() OVER (PARTITION BY [job_id] ORDER BY [run_date] DESC, [run_time] DESC)
21 | FROM [msdb].[dbo].[sysjobhistory] [jh]
22 | WHERE [step_id] = 0
23 | )
24 | SELECT
25 | [job_name] = [j].[name]
26 | ,[last_run_date] = CONVERT(nvarchar(16), [msdb].[dbo].[agent_datetime]([jh].[run_date], [jh].[run_time]), 120)
27 | ,[nex_run_date] = CONVERT(nvarchar(16), [msdb].[dbo].[agent_datetime]([js].[next_run_date], [js].[next_run_time]), 120)
28 | ,[run_status] = CASE [jh].[run_status]
29 | WHEN 0 THEN 'Failed'
30 | WHEN 1 THEN 'Success'
31 | WHEN 2 THEN 'Retry'
32 | WHEN 3 THEN 'Canceled'
33 | WHEN 4 THEN 'In progress'
34 | END
35 | ,[run_duration] = STUFF(STUFF(STUFF(RIGHT(REPLICATE('0', 8) + CAST([jh].[run_duration] as varchar(8)), 8), 3, 0, ':'), 6, 0, ':'), 9, 0, ':')
36 | FROM [msdb].[dbo].[sysjobs] [j]
37 | INNER JOIN [cte_last_job_run] [jh] ON [j].[job_id] = [jh].[job_id]
38 | INNER JOIN [msdb].[dbo].[sysjobschedules] [js] ON [js].[job_id] = [j].[job_id]
39 | WHERE [jh].[rn] = 1
40 | AND ([msdb].[dbo].[agent_datetime]([jh].[run_date], [jh].[run_time]) >= @date_from OR @date_from IS NULL)
41 | AND ([j].[name] = @job_name OR @job_name IS NULL);
42 |
43 | END;
--------------------------------------------------------------------------------
/SqlTelegram/monitor/Stored Procedures/usp_check_job_failed.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [monitor].[usp_check_job_failed]
2 | AS
3 | BEGIN
4 | SET NOCOUNT ON ;
5 |
6 | DECLARE
7 | @message nvarchar(max)
8 | ,@threshold bigint
9 | ,@check_date datetime
10 | ,@last_check_date datetime;
11 |
12 | SELECT @threshold = [t].[threshold]
13 | FROM [monitor].[threshold] [t]
14 | WHERE [t].[counter] = N'lock';
15 |
16 | SET @check_date = GETDATE();
17 |
18 | SELECT @last_check_date = [s].[value_date]
19 | FROM [dbo].[settings] [s]
20 | WHERE [s].[name] = N'job_failed_last_check_date';
21 |
22 | SELECT @message = STUFF
23 | ((
24 | SELECT CHAR(10)
25 | + N'Задание [' + [j].[name] + N'] завершилось с ошибкой ' + CHAR(10)
26 | + N'Шаг: ' + [s].[step_name] + CHAR(10)
27 | + N'Время запуска: ' + CONVERT(nvarchar(30), [msdb].[dbo].[agent_datetime]([h].[run_date], [h].[run_time]), 120) + CHAR(10)
28 | + N'Длительность выполнения: ' + CAST((([h].[run_duration]/10000*3600 + ([h].[run_duration]/100)%100*60 + [h].[run_duration]%100 + 31 ) / 60) AS nvarchar(max)) + N' мин' + CHAR(10)
29 | FROM [msdb].[dbo].[sysjobhistory] [h]
30 | INNER JOIN [msdb].[dbo].[sysjobs] [j] ON [j].[job_id] = [h].[job_id]
31 | INNER JOIN [msdb].[dbo].[sysjobsteps] [s] ON [s].[job_id] = [j].[job_id]
32 | WHERE [h].[step_id] <> 0
33 | AND [msdb].[dbo].[agent_datetime]([h].[run_date], [h].[run_time]) > @last_check_date
34 | AND [msdb].[dbo].[agent_datetime]([h].[run_date], [h].[run_time]) <= @check_date
35 | AND [h].[run_status] = 0 -- Failure
36 | FOR XML PATH(N''))
37 | , 1, 1, N''
38 | );
39 |
40 | UPDATE [dbo].[settings]
41 | SET [value_date] = @check_date
42 | WHERE [name] = N'job_failed_last_check_date';
43 |
44 | IF @message IS NOT NULL
45 | EXEC [dbo].[usp_SendMessage]
46 | @message = @message;
47 |
48 | END;
--------------------------------------------------------------------------------
/SqlTelegram/monitor/Stored Procedures/usp_get_top_queries.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [monitor].[usp_get_top_queries]
2 | (
3 | @date_from datetime = NULL
4 | ,@db_name sysname = NULL
5 | ,@object_name sysname = NULL
6 | )
7 | AS
8 | BEGIN
9 |
10 | SET NOCOUNT ON;
11 |
12 | SET @date_from = ISNULL(@date_from, DATEADD(minute, -30, GETDATE()));
13 |
14 | SELECT TOP (10)
15 | --[query_hash] = [query_stats].[query_hash]
16 | --,
17 | [db_name] = MIN([query_stats].[db_name])
18 | ,[object_name] = MIN([query_stats].[object_name])
19 | ,[execution_count] = SUM([query_stats].[execution_count])
20 | ,[min_elapsed_time] = MIN([query_stats].[min_elapsed_time])
21 | ,[avg_elapsed_time] = SUM([query_stats].[total_elapsed_time])/SUM([query_stats].[execution_count])
22 | ,[max_elapsed_time] = MAX([query_stats].[max_elapsed_time])
23 | ,[statement] = MIN([query_stats].[statement_text])
24 | FROM (
25 | SELECT
26 | [qs].[query_hash]
27 | ,[qs].[execution_count]
28 | ,[qs].[min_elapsed_time]
29 | ,[qs].[total_elapsed_time]
30 | ,[qs].[max_elapsed_time]
31 | ,[statement_text] = SUBSTRING([st].[text], ([qs].[statement_start_offset] / 2) + 1, (
32 | (
33 | CASE [statement_end_offset]
34 | WHEN - 1
35 | THEN DATALENGTH([st].[text])
36 | ELSE [qs].[statement_end_offset]
37 | END - [qs].[statement_start_offset]
38 | ) / 2
39 | ) + 1)
40 | ,[db_name] = DB_NAME([st].[dbid])
41 | ,[object_name] = OBJECT_NAME([st].[objectid], [st].[dbid])
42 | FROM sys.dm_exec_query_stats [qs]
43 | CROSS APPLY sys.dm_exec_sql_text([qs].[sql_handle]) [st]
44 | WHERE [qs].[last_execution_time] >= @date_from
45 | AND (DB_NAME([st].[dbid]) = @db_name OR @db_name IS NULL)
46 | AND (OBJECT_NAME([st].[objectid], [st].[dbid]) = @object_name OR @object_name IS NULL)
47 | ) AS [query_stats]
48 | GROUP BY [query_stats].[query_hash]
49 | ORDER BY [max_elapsed_time] DESC;
50 |
51 | END;
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Stored Procedures/usp_request_access.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [dbo].[usp_request_access]
2 | AS
3 | BEGIN
4 | SET NOCOUNT ON;
5 |
6 | DECLARE
7 | @chat_id bigint
8 | ,@url nvarchar(max)
9 | ,@http_headers xml
10 | ,@offset bigint
11 | ,@update_timeout bigint
12 | ,@limit bigint
13 | ,@num_rows bigint
14 | ,@num_cols bigint
15 | ,@col_width bigint
16 | ,@success bit
17 | ,@response nvarchar(max)
18 | ,@error nvarchar(max)
19 | ,@query_url nvarchar(max)
20 | ,@json_update nvarchar(max) = '{}'
21 | ,@user_id bigint
22 | ,@name nvarchar(50);
23 |
24 | EXEC [dbo].[usp_get_settings]
25 | @url = @url OUTPUT
26 | ,@http_headers = @http_headers OUTPUT
27 | ,@chat_id = @chat_id OUTPUT
28 | ,@last_update_id = @offset OUTPUT
29 | ,@update_timeout = @update_timeout OUTPUT
30 | ,@limit = @limit OUTPUT
31 | ,@num_rows = @num_rows OUTPUT
32 | ,@num_cols = @num_cols OUTPUT
33 | ,@col_width = @col_width OUTPUT;
34 |
35 | SET @offset = ISNULL(@offset + 1, 0);
36 |
37 | SET @query_url = CONCAT(@url, 'getUpdates');
38 | SET @json_update = JSON_MODIFY(@json_update,'$.timeout', @update_timeout);
39 | SET @json_update = JSON_MODIFY(@json_update,'$.offset', @offset);
40 | SET @json_update = JSON_MODIFY(@json_update,'$.limit', @limit);
41 |
42 |
43 | EXEC [dbo].[usp_HttpPost]
44 | @url = @query_url,
45 | @headerXml = @http_headers,
46 | @requestBody = @json_update,
47 | @success = @success OUTPUT,
48 | @response = @response OUTPUT,
49 | @error = @error OUTPUT;
50 |
51 | SELECT TOP (1)
52 | @user_id = [user_id]
53 | ,@name = [name]
54 | FROM OPENJSON (@response, N'$.result')
55 | WITH
56 | (
57 | [text] nvarchar(max) N'$.message.text'
58 | ,[chat_id] bigint N'$.message.chat.id'
59 | ,[update_id] bigint N'$.update_id'
60 | ,[user_id] bigint N'$.message.from.id'
61 | ,[name] nvarchar(50) N'$.message.from.username'
62 | )
63 | WHERE [chat_id] = @chat_id
64 | AND [text] LIKE '/request_access%'
65 | ORDER BY [update_id] DESC;
66 |
67 | EXEC [dbo].[usp_add_user]
68 | @user_id = @user_id
69 | ,@name = @name
70 | ,@authorized = 0;
71 |
72 | SELECT [response] = 'User created'
73 |
74 | END
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | # SQL telegram bot
2 |
3 | # The purpose
4 | To send and receive messages to/from telegram bot natively with MS SQL server (by stored procedures)
5 |
6 | # Prerequsites
7 | * SQL Server 2016 or higher
8 | * Registered Telegram bot [check here](https://docs.microsoft.com/en-us/azure/bot-service/bot-service-channel-connect-telegram?view=azure-bot-service-4.0) via [Bot Father](https://telegram.me/botfather)
9 |
10 |
11 | # How to install
12 | 1. Clone repo ```git clone https://github.com/gleberof/SQL-telegram-bot.git```
13 | 2. Run setup.sql (new DB \[telegram\] with all nesessary procedures will be created)
14 | 3. Send a message to your bot directly in Telegram (it will help to identify your chat ID). If you're going to use the bot within a group - you need to set up the bot as one of the admins of that group.
15 | 4. Open ```Configure.sql```. Set bot_token given by [Bot Father](https://telegram.me/botfather). It will automatically assign chat_id from the last message to the bot or chat.
16 | 5. Run ```Jobs.sql``` - to enable jobs (it's checking reuests to bot automatically)
17 | 6. To be able to run SELECT and you need to authorize you account with bot:
18 | * Find your bot in telegram or open the chat channel where the bot already added
19 | * Send the ```/request_access@[your_bot_name]``` command to bot - it's add your telegram ID to usesr table
20 | * Open telegram.dbo.users table and find your nickname and set flag [authorized] to 1
21 | * Now you can do selects with bot
22 |
23 |
24 | # How to use
25 | 1. Send a message from SQL by ```EXEC [dbo].[usp_SendMessage] @message = N'Hello World!'```
26 | 2. Setup commands.
27 |
28 | Please check ```[telegram].[dbo].[commands]``` table to learn how to configure new commands (we setup few during initial [setup](#how-to-install))
29 |
30 | 
31 |
32 | 3. Setup progress bar for backups. It's almost confugured and run by job (please try backup on you server)
33 |
34 | 
35 |
36 | 4. Execute SQL selects. It's almost ready to execute commands - put ```*``` symbol before select.
37 |
38 | 
39 |
40 | 5. Setup monitoring. Please check ```[telegram].[monitor].[threshold]``` to change threshold for alerts
41 |
42 | # Contacts
43 | Please do not hesitate to address us in case of questions if any:
44 | * gleberof @ gmail.com
45 | * efremovfedorofficial @ gmail.com
46 |
--------------------------------------------------------------------------------
/SqlTelegram/monitor/Stored Procedures/usp_check_disk_latency.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [monitor].[usp_check_disk_latency]
2 | AS
3 | BEGIN
4 | SET NOCOUNT ON ;
5 |
6 | DECLARE
7 | @message nvarchar(max)
8 | ,@threshold int
9 | ,@cpu_value int;
10 |
11 | SELECT @threshold = [t].[threshold]
12 | FROM [monitor].[threshold] [t]
13 | WHERE [t].[counter] = N'disk_latency';
14 |
15 | IF OBJECT_ID('tempdb..#t_disk_latency') IS NOT NULL
16 | DROP TABLE [#t_disk_latency];
17 |
18 | SELECT
19 | [vfs].[database_id]
20 | ,[vfs].[file_id]
21 | ,[vfs].[sample_ms]
22 | ,[vfs].[num_of_reads]
23 | ,[vfs].[num_of_writes]
24 | ,[vfs].[io_stall_read_ms]
25 | ,[vfs].[io_stall_write_ms]
26 | INTO [#t_disk_latency]
27 | FROM sys.dm_io_virtual_file_stats (NULL, NULL) [vfs];
28 |
29 | ;WITH [file_usage_stats] AS
30 | (
31 | SELECT
32 | [db_name] = DB_NAME([cur].[database_id])
33 | ,[file_type] = [mf].[type_desc]
34 | ,[read_latency] = IIF(([cur].[num_of_reads] - [prev].[num_of_reads]) = 0
35 | ,0
36 | ,(([cur].[io_stall_read_ms] - [prev].[io_stall_read_ms]) / ([cur].[num_of_reads] - [prev].[num_of_reads]))
37 | )
38 | ,[write_latency] = IIF(([cur].[num_of_writes] - [prev].[num_of_writes]) = 0
39 | ,0
40 | ,(([cur].[io_stall_write_ms] - [prev].[io_stall_write_ms]) / ([cur].[num_of_writes] - [prev].[num_of_writes]))
41 | )
42 | FROM [#t_disk_latency] [cur]
43 | INNER JOIN [monitor].[disk_latency] [prev] ON [prev].[database_id] = [cur].[database_id]
44 | AND [prev].[file_id] = [cur].[file_id]
45 | INNER JOIN sys.master_files [mf] ON [mf].[database_id] = [cur].[database_id]
46 | AND [mf].[file_id] = [cur].[file_id]
47 | )
48 | SELECT @message = STUFF
49 | ((
50 | SELECT CHAR(10)
51 | + N'Время выполнения операции ' + IIF([unpvt].[io_type] = N'read_latency', N'чтения: ', N'записи: ') + CAST([unpvt].[latency] AS nvarchar(max)) + N' мсек' + CHAR(10)
52 | + N'База данных: ' + [unpvt].[db_name] + CHAR(10)
53 | + N'Тип файла: ' + [unpvt].[file_type] + CHAR(10)
54 | FROM
55 | (
56 | SELECT
57 | [db_name] = [fus].[db_name]
58 | ,[file_type] = [fus].[file_type]
59 | ,[read_latency] = [fus].[read_latency]
60 | ,[write_latency] = [fus].[write_latency]
61 | FROM [file_usage_stats] [fus]
62 | ) [p]
63 | UNPIVOT
64 | (
65 | [latency] FOR [io_type] IN ([read_latency], [write_latency])
66 | ) AS [unpvt]
67 | WHERE [unpvt].[latency] >= @threshold
68 | FOR XML PATH(N''))
69 | , 1, 1, N''
70 | );
71 |
72 | DELETE
73 | FROM [monitor].[disk_latency];
74 |
75 | INSERT INTO [monitor].[disk_latency]
76 | (
77 | [database_id]
78 | ,[file_id]
79 | ,[sample_ms]
80 | ,[num_of_reads]
81 | ,[num_of_writes]
82 | ,[io_stall_read_ms]
83 | ,[io_stall_write_ms]
84 | )
85 | SELECT
86 | [tdl].[database_id]
87 | ,[tdl].[file_id]
88 | ,[tdl].[sample_ms]
89 | ,[tdl].[num_of_reads]
90 | ,[tdl].[num_of_writes]
91 | ,[tdl].[io_stall_read_ms]
92 | ,[tdl].[io_stall_write_ms]
93 | FROM [#t_disk_latency] [tdl];
94 |
95 | IF @message IS NOT NULL
96 | EXEC [dbo].[usp_SendMessage]
97 | @message = @message;
98 |
99 | END;
--------------------------------------------------------------------------------
/SqlTelegram/dbo/Stored Procedures/usp_get_chat_updates.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [dbo].[usp_get_chat_updates]
2 | AS
3 | BEGIN
4 | SET NOCOUNT ON;
5 |
6 | DECLARE
7 | @chat_id bigint
8 | ,@url nvarchar(max)
9 | ,@http_headers xml
10 | ,@offset bigint
11 | ,@update_timeout bigint
12 | ,@limit bigint
13 | ,@num_rows bigint
14 | ,@num_cols bigint
15 | ,@col_width bigint
16 | ,@success bit
17 | ,@response nvarchar(max)
18 | ,@error nvarchar(max)
19 | ,@query_url nvarchar(max)
20 | ,@json_update nvarchar(max) = '{}'
21 | ,@json_chat nvarchar(max) = N'{}'
22 | ,@command_response nvarchar(max)
23 | ,@text nvarchar(max)
24 | ,@message_url nvarchar(max)
25 | ,@message nvarchar(max)
26 | ,@query nvarchar(max)
27 | ,@update_id bigint
28 | ,@user_id bigint
29 | ,@bot_name nvarchar(max);
30 |
31 | EXEC [dbo].[usp_get_settings]
32 | @url = @url OUTPUT
33 | ,@http_headers = @http_headers OUTPUT
34 | ,@chat_id = @chat_id OUTPUT
35 | ,@last_update_id = @offset OUTPUT
36 | ,@update_timeout = @update_timeout OUTPUT
37 | ,@limit = @limit OUTPUT
38 | ,@num_rows = @num_rows OUTPUT
39 | ,@num_cols = @num_cols OUTPUT
40 | ,@col_width = @col_width OUTPUT
41 | ,@bot_name = @bot_name OUTPUT;
42 |
43 | SET @offset = ISNULL(@offset + 1, 0);
44 |
45 | SET @query_url = CONCAT(@url, 'getUpdates');
46 | SET @json_update = JSON_MODIFY(@json_update,'$.timeout', @update_timeout);
47 | SET @json_update = JSON_MODIFY(@json_update,'$.offset', @offset);
48 | SET @json_update = JSON_MODIFY(@json_update,'$.limit', @limit);
49 |
50 | EXEC [dbo].[usp_HttpPost]
51 | @url = @query_url,
52 | @headerXml = @http_headers,
53 | @requestBody = @json_update,
54 | @success = @success OUTPUT,
55 | @response = @response OUTPUT,
56 | @error = @error OUTPUT;
57 |
58 | SELECT TOP (1)
59 | @text = [text]
60 | ,@update_id = [update_id]
61 | ,@user_id = [user_id]
62 | FROM OPENJSON (@response, N'$.result')
63 | WITH
64 | (
65 | [text] nvarchar(max) N'$.message.text'
66 | ,[chat_id] bigint N'$.message.chat.id'
67 | ,[update_id] bigint N'$.update_id'
68 | ,[user_id] bigint N'$.message.from.id'
69 | )
70 | WHERE [chat_id] = @chat_id
71 | ORDER BY [update_id] DESC;
72 |
73 | IF EXISTS
74 | (
75 | SELECT 1
76 | FROM [dbo].[users] [u]
77 | WHERE [u].[user_id] = @user_id
78 | AND [u].[authorized] = 1
79 | )
80 | OR @text LIKE '/request_access%'
81 | BEGIN
82 |
83 | EXEC [dbo].[usp_Message2Command]
84 | @json = @response
85 | ,@bot_name = @bot_name
86 | ,@chat_id = @chat_id
87 | ,@response = @command_response OUTPUT;
88 |
89 | IF @command_response IS NOT NULL
90 | BEGIN
91 | SET @message_url = CONCAT(@url, N'sendMessage');
92 | SET @json_chat = N'{}';
93 | SET @json_chat = JSON_MODIFY(@json_chat, '$.text', @command_response);
94 | SET @json_chat = JSON_MODIFY(@json_chat, '$.chat_id', @chat_id);
95 | SET @json_chat = JSON_MODIFY(@json_chat, '$.parse_mode', 'Markdown');
96 |
97 | EXEC [dbo].[usp_HttpPost]
98 | @url = @message_url,
99 | @headerXml = @http_headers,
100 | @requestBody = @json_chat,
101 | @success = @success OUTPUT,
102 | @response = @command_response OUTPUT,
103 | @error = @error OUTPUT;
104 | END;
105 |
106 | IF LEFT(@text, 1) = N'*'
107 | BEGIN
108 |
109 | SET @query = RIGHT(@text, LEN(@text) - 1);
110 |
111 | EXEC [dbo].[usp_SQL2string]
112 | @SqlString = @query,
113 | @num_rows = @num_rows,
114 | @num_cols = @num_cols,
115 | @col_width = @col_width,
116 | @list_width = N'',
117 | @response = @message OUTPUT
118 |
119 | SET @message_url = CONCAT(@url, N'sendMessage');
120 | SET @json_chat = N'{}';
121 | SET @json_chat = JSON_MODIFY(@json_chat, '$.text', @message);
122 | SET @json_chat = JSON_MODIFY(@json_chat, '$.chat_id', @chat_id);
123 | SET @json_chat = JSON_MODIFY(@json_chat, '$.parse_mode', 'Markdown');
124 |
125 | EXEC [dbo].[usp_HttpPost]
126 | @url = @message_url,
127 | @headerXml = @http_headers,
128 | @requestBody = @json_chat,
129 | @success = @success OUTPUT,
130 | @response = @response OUTPUT,
131 | @error = @error OUTPUT;
132 |
133 | END;
134 |
135 | END;
136 |
137 | IF @update_id IS NOT NULL
138 | UPDATE [dbo].[settings]
139 | SET [value] = @update_id
140 | WHERE [name] = N'last_update_id';
141 |
142 | END;
--------------------------------------------------------------------------------
/Configure.sql:
--------------------------------------------------------------------------------
1 | USE [telegram];
2 | GO
3 |
4 | -- Put bot token here
5 | DECLARE @bot_token nvarchar(max) = N'';
6 |
7 | SET @bot_token = @bot_token + N'/'
8 |
9 | INSERT [dbo].[settings] ([name], [value], [value_str], [value_date]) VALUES (N'bot_token', NULL, @bot_token, NULL)
10 | GO
11 |
12 |
13 | -- Send message in chat
14 |
15 |
16 | -- Get chat_id
17 | DECLARE @chat_id bigint;
18 |
19 | EXEC [dbo].[usp_GetChatId]
20 | @chat_id = @chat_id OUTPUT;
21 |
22 | INSERT [dbo].[settings] ([name], [value], [value_str], [value_date]) VALUES (N'chat_id', @chat_id, NULL, NULL)
23 | GO
24 |
25 |
26 | -- Get Bot name
27 | DECLARE @bot_name nvarchar(max);
28 |
29 | EXEC [dbo].[usp_get_bot_name]
30 | @bot_name = @bot_name OUTPUT;
31 |
32 | INSERT [dbo].[settings] ([name], [value], [value_str], [value_date]) VALUES (N'bot_name', NULL , @bot_name, NULL)
33 | GO
34 |
35 |
36 |
37 | INSERT [dbo].[settings] ([name], [value], [value_str], [value_date]) VALUES (N'col_width', 10, NULL, NULL)
38 | GO
39 | INSERT [dbo].[settings] ([name], [value], [value_str], [value_date]) VALUES (N'http_headers', NULL, N'', NULL)
40 | GO
41 | INSERT [dbo].[settings] ([name], [value], [value_str], [value_date]) VALUES (N'last_check_date', NULL, NULL, NULL)
42 | GO
43 | INSERT [dbo].[settings] ([name], [value], [value_str], [value_date]) VALUES (N'last_update_id', 100885916, NULL, NULL)
44 | GO
45 | INSERT [dbo].[settings] ([name], [value], [value_str], [value_date]) VALUES (N'limit', 10, NULL, NULL)
46 | GO
47 | INSERT [dbo].[settings] ([name], [value], [value_str], [value_date]) VALUES (N'num_cols', 8, NULL, NULL)
48 | GO
49 | INSERT [dbo].[settings] ([name], [value], [value_str], [value_date]) VALUES (N'num_rows', 8, NULL, NULL)
50 | GO
51 | INSERT [dbo].[settings] ([name], [value], [value_str], [value_date]) VALUES (N'offset', 0, NULL, NULL)
52 | GO
53 | INSERT [dbo].[settings] ([name], [value], [value_str], [value_date]) VALUES (N'update_timeout', 2, NULL, NULL)
54 | GO
55 |
56 |
57 |
58 | INSERT [dbo].[commands] ([command], [query], [description], [columns_width]) VALUES (N'job_execution_stats', N'EXEC [monitor].[usp_get_job_execution_stats]', N'Get last job execution stats', N'10,16,16,3,9')
59 | GO
60 | INSERT [dbo].[commands] ([command], [query], [description], [columns_width]) VALUES (N'jobs', N'SELECT
61 | [j].[name]
62 | ,[ja].[session_id]
63 | ,[start_date] = CONVERT(nvarchar(8), [ja].[start_execution_date], 114)
64 | ,[step_id] = ISNULL([ja].[last_executed_step_id], 0) + 1
65 | ,[js].[step_name]
66 | FROM [msdb].[dbo].[sysjobactivity] [ja]
67 | INNER JOIN [msdb].[dbo].[sysjobs] [j] ON [j].[job_id] = [ja].[job_id]
68 | LEFT JOIN [msdb].[dbo].[sysjobsteps] [js] ON [js].[job_id] = [j].[job_id]
69 | AND ISNULL([ja].[last_executed_step_id], 0) + 1 = [js].[step_id]
70 | WHERE [ja].[session_id] = (SELECT TOP 1 [session_id] FROM [msdb].[dbo].[syssessions] ORDER BY [agent_start_date] DESC)
71 | AND [ja].[start_execution_date] IS NOT NULL
72 | AND [ja].[stop_execution_date] IS NULL', N'Get current jobs', N'10,4,10,2,10')
73 | GO
74 | INSERT [dbo].[commands] ([command], [query], [description], [columns_width]) VALUES (N'sessions', N'select session_id, status, blocking_session_id, wait_type,wait_time, wait_resource
75 | from sys.dm_exec_requests a
76 | where status <> ''background''
77 | and session_id > 40
78 | order by wait_time desc', N'Get current sessions', N'3,3,3,10,10,10')
79 | GO
80 | INSERT [dbo].[commands] ([command], [query], [description], [columns_width]) VALUES (N'top_queries', N'EXEC [monitor].[usp_get_top_queries]', N'Get top 10 queries in the last 30 minutes', N'6,12,4,4,4,4,30')
81 | GO
82 | INSERT [dbo].[commands] ([command], [query], [description], [columns_width]) VALUES (N'version', N'SELECT @@VERSION', N'Get SQL Server version', N'600')
83 | GO
84 | INSERT [dbo].[commands] ([command], [query], [description], [columns_width]) VALUES (N'request_access', N'EXEC [dbo].[usp_request_access]', N'Request access to use commands', N'12')
85 | GO
86 | INSERT [dbo].[commands] ([command], [query], [description], [columns_width]) VALUES (N'Ping', N'EXEC [dbo].[ping] @param', N'Ping Specified Server e.e. /ping@Telegram_bot servername01', N'60')
87 | GO
88 |
89 |
90 | INSERT [monitor].[threshold] ([counter], [threshold], [type]) VALUES (N'cpu_usage', CAST(80.00 AS Decimal(18, 2)), N'percent')
91 | GO
92 | INSERT [monitor].[threshold] ([counter], [threshold], [type]) VALUES (N'disk_free_space_pct', CAST(10.00 AS Decimal(18, 2)), N'percent')
93 | GO
94 | INSERT [monitor].[threshold] ([counter], [threshold], [type]) VALUES (N'disk_latency', CAST(25.00 AS Decimal(18, 2)), N'msec')
95 | GO
96 | INSERT [monitor].[threshold] ([counter], [threshold], [type]) VALUES (N'lock_wait', CAST(60.00 AS Decimal(18, 2)), N'sec')
97 | GO
98 |
--------------------------------------------------------------------------------
/.gitignore:
--------------------------------------------------------------------------------
1 | ## Ignore Visual Studio temporary files, build results, and
2 | ## files generated by popular Visual Studio add-ons.
3 |
4 | # User-specific files
5 | *.suo
6 | *.user
7 | *.userosscache
8 | *.sln.docstates
9 |
10 | # User-specific files (MonoDevelop/Xamarin Studio)
11 | *.userprefs
12 |
13 | # Build results
14 | [Dd]ebug/
15 | [Dd]ebugPublic/
16 | [Rr]elease/
17 | [Rr]eleases/
18 | x64/
19 | x86/
20 | bld/
21 | [Bb]in/
22 | [Oo]bj/
23 | [Ll]og/
24 |
25 | # Visual Studio 2015 cache/options directory
26 | .vs/
27 | # Uncomment if you have tasks that create the project's static files in wwwroot
28 | #wwwroot/
29 |
30 | # MSTest test Results
31 | [Tt]est[Rr]esult*/
32 | [Bb]uild[Ll]og.*
33 |
34 | # NUNIT
35 | *.VisualState.xml
36 | TestResult.xml
37 |
38 | # Build Results of an ATL Project
39 | [Dd]ebugPS/
40 | [Rr]eleasePS/
41 | dlldata.c
42 |
43 | # DNX
44 | project.lock.json
45 | project.fragment.lock.json
46 | artifacts/
47 |
48 | *_i.c
49 | *_p.c
50 | *_i.h
51 | *.ilk
52 | *.meta
53 | *.obj
54 | *.pch
55 | *.pdb
56 | *.pgc
57 | *.pgd
58 | *.rsp
59 | *.sbr
60 | *.tlb
61 | *.tli
62 | *.tlh
63 | *.tmp
64 | *.tmp_proj
65 | *.log
66 | *.vspscc
67 | *.vssscc
68 | .builds
69 | *.pidb
70 | *.svclog
71 | *.scc
72 |
73 | # Chutzpah Test files
74 | _Chutzpah*
75 |
76 | # Visual C++ cache files
77 | ipch/
78 | *.aps
79 | *.ncb
80 | *.opendb
81 | *.opensdf
82 | *.sdf
83 | *.cachefile
84 | *.VC.db
85 | *.VC.VC.opendb
86 |
87 | # Visual Studio profiler
88 | *.psess
89 | *.vsp
90 | *.vspx
91 | *.sap
92 |
93 | # TFS 2012 Local Workspace
94 | $tf/
95 |
96 | # Guidance Automation Toolkit
97 | *.gpState
98 |
99 | # ReSharper is a .NET coding add-in
100 | _ReSharper*/
101 | *.[Rr]e[Ss]harper
102 | *.DotSettings.user
103 |
104 | # JustCode is a .NET coding add-in
105 | .JustCode
106 |
107 | # TeamCity is a build add-in
108 | _TeamCity*
109 |
110 | # DotCover is a Code Coverage Tool
111 | *.dotCover
112 |
113 | # NCrunch
114 | _NCrunch_*
115 | .*crunch*.local.xml
116 | nCrunchTemp_*
117 |
118 | # MightyMoose
119 | *.mm.*
120 | AutoTest.Net/
121 |
122 | # Web workbench (sass)
123 | .sass-cache/
124 |
125 | # Installshield output folder
126 | [Ee]xpress/
127 |
128 | # DocProject is a documentation generator add-in
129 | DocProject/buildhelp/
130 | DocProject/Help/*.HxT
131 | DocProject/Help/*.HxC
132 | DocProject/Help/*.hhc
133 | DocProject/Help/*.hhk
134 | DocProject/Help/*.hhp
135 | DocProject/Help/Html2
136 | DocProject/Help/html
137 |
138 | # Click-Once directory
139 | publish/
140 |
141 | # Publish Web Output
142 | *.[Pp]ublish.xml
143 | *.azurePubxml
144 | # TODO: Comment the next line if you want to checkin your web deploy settings
145 | # but database connection strings (with potential passwords) will be unencrypted
146 | #*.pubxml
147 | *.publishproj
148 |
149 | # Microsoft Azure Web App publish settings. Comment the next line if you want to
150 | # checkin your Azure Web App publish settings, but sensitive information contained
151 | # in these scripts will be unencrypted
152 | PublishScripts/
153 |
154 | # NuGet Packages
155 | *.nupkg
156 | # The packages folder can be ignored because of Package Restore
157 | **/packages/*
158 | # except build/, which is used as an MSBuild target.
159 | !**/packages/build/
160 | # Uncomment if necessary however generally it will be regenerated when needed
161 | #!**/packages/repositories.config
162 | # NuGet v3's project.json files produces more ignoreable files
163 | *.nuget.props
164 | *.nuget.targets
165 |
166 | # Microsoft Azure Build Output
167 | csx/
168 | *.build.csdef
169 |
170 | # Microsoft Azure Emulator
171 | ecf/
172 | rcf/
173 |
174 | # Windows Store app package directories and files
175 | AppPackages/
176 | BundleArtifacts/
177 | Package.StoreAssociation.xml
178 | _pkginfo.txt
179 |
180 | # Visual Studio cache files
181 | # files ending in .cache can be ignored
182 | *.[Cc]ache
183 | # but keep track of directories ending in .cache
184 | !*.[Cc]ache/
185 |
186 | # Others
187 | ClientBin/
188 | ~$*
189 | *~
190 | *.dbmdl
191 | *.dbproj.schemaview
192 | *.jfm
193 | *.pfx
194 | *.publishsettings
195 | node_modules/
196 | orleans.codegen.cs
197 |
198 | # Since there are multiple workflows, uncomment next line to ignore bower_components
199 | # (https://github.com/github/gitignore/pull/1529#issuecomment-104372622)
200 | #bower_components/
201 |
202 | # RIA/Silverlight projects
203 | Generated_Code/
204 |
205 | # Backup & report files from converting an old project file
206 | # to a newer Visual Studio version. Backup files are not needed,
207 | # because we have git ;-)
208 | _UpgradeReport_Files/
209 | Backup*/
210 | UpgradeLog*.XML
211 | UpgradeLog*.htm
212 |
213 | # SQL Server files
214 | *.mdf
215 | *.ldf
216 |
217 | # Business Intelligence projects
218 | *.rdl.data
219 | *.bim.layout
220 | *.bim_*.settings
221 |
222 | # Microsoft Fakes
223 | FakesAssemblies/
224 |
225 | # GhostDoc plugin setting file
226 | *.GhostDoc.xml
227 |
228 | # Node.js Tools for Visual Studio
229 | .ntvs_analysis.dat
230 |
231 | # Visual Studio 6 build log
232 | *.plg
233 |
234 | # Visual Studio 6 workspace options file
235 | *.opt
236 |
237 | # Visual Studio LightSwitch build output
238 | **/*.HTMLClient/GeneratedArtifacts
239 | **/*.DesktopClient/GeneratedArtifacts
240 | **/*.DesktopClient/ModelManifest.xml
241 | **/*.Server/GeneratedArtifacts
242 | **/*.Server/ModelManifest.xml
243 | _Pvt_Extensions
244 |
245 | # Paket dependency manager
246 | .paket/paket.exe
247 | paket-files/
248 |
249 | # FAKE - F# Make
250 | .fake/
251 |
252 | # JetBrains Rider
253 | .idea/
254 | *.sln.iml
255 |
256 | # CodeRush
257 | .cr/
258 |
259 | # Python Tools for Visual Studio (PTVS)
260 | __pycache__/
261 | *.pyc
--------------------------------------------------------------------------------
/SqlTelegram/monitor/Stored Procedures/usp_get_progress.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [monitor].[usp_get_progress]
2 | AS
3 | BEGIN
4 | SET NOCOUNT ON;
5 |
6 | DECLARE
7 | @chat_id bigint
8 | ,@url nvarchar(max)
9 | ,@http_headers xml
10 | ,@json_chat nvarchar(max) = N'{}'
11 | ,@message_url nvarchar(max)
12 | ,@success bit
13 | ,@response nvarchar(max)
14 | ,@error nvarchar(max)
15 | ,@message nvarchar(max)
16 | ,@message_id bigint
17 | ,@session_id bigint
18 | ,@command nvarchar(50)
19 | ,@database sysname
20 | ,@start_time datetime
21 | ,@estimated_completion_time datetime
22 | ,@percent_complete numeric(5,2);
23 |
24 | EXEC [dbo].[usp_get_settings]
25 | @url = @url OUTPUT
26 | ,@http_headers = @http_headers OUTPUT
27 | ,@chat_id = @chat_id OUTPUT;
28 |
29 | IF OBJECT_ID('tempdb..#t_progress') IS NOT NULL
30 | DROP TABLE [#t_progress];
31 |
32 | SELECT
33 | [session_id] = [r].[session_id]
34 | ,[command] = [r].[command]
35 | ,[database] = DB_NAME([r].[database_id])
36 | ,[start_time] = [r].[start_time]
37 | ,[estimated_completion_time] = DATEADD(second, [r].[estimated_completion_time]/1000, GETDATE())
38 | ,[percent_complete] = [r].[percent_complete]
39 | INTO [#t_progress]
40 | FROM sys.dm_exec_requests [r]
41 | WHERE [r].[command] IN ('BACKUP DATABASE','RESTORE DATABASE')
42 |
43 | DECLARE [cur_progress] CURSOR LOCAL FAST_FORWARD FOR
44 | SELECT
45 | [session_id] = [t].[session_id]
46 | ,[command] = [t].[command]
47 | ,[database] = [t].[database]
48 | ,[start_time] = [t].[start_time]
49 | ,[estimated_completion_time] = [t].[estimated_completion_time]
50 | ,[percent_complete] = [t].[percent_complete]
51 | ,[message_id] = [p].[message_id]
52 | FROM [#t_progress] [t]
53 | LEFT JOIN [monitor].[progress] [p] ON [p].[session_id] = [t].[session_id]
54 |
55 | OPEN [cur_progress];
56 |
57 | WHILE 1 = 1
58 | BEGIN
59 | FETCH NEXT FROM [cur_progress] INTO @session_id, @command, @database, @start_time, @estimated_completion_time, @percent_complete, @message_id
60 | IF @@FETCH_STATUS <> 0 BREAK;
61 |
62 | SET @message = CONCAT(
63 | N'Сессия: ' + CONVERT(nvarchar(20), @session_id) + CHAR(10)
64 | ,N'База: ' + @database + CHAR(10)
65 | ,N'Команда: ' + @command + CHAR(10)
66 | ,N'Время начала: ' + CONVERT(nvarchar(50), @start_time, 120) + CHAR(10)
67 | ,N'Прогнозируемое время завершения: ' + CONVERT(nvarchar(50), @estimated_completion_time, 120) + CHAR(10)
68 | ,REPLICATE(N'▓', FLOOR(@percent_complete/10)) + REPLICATE(N'░', 10 - FLOOR(@percent_complete/10)), CONVERT(nvarchar(6), @percent_complete) + N'%' + CHAR(10)
69 | );
70 | SET @json_chat = N'{}';
71 | SET @json_chat = JSON_MODIFY(@json_chat, '$.text', @message);
72 | SET @json_chat = JSON_MODIFY(@json_chat, '$.chat_id', @chat_id);
73 |
74 | IF @message_id IS NOT NULL
75 | BEGIN
76 |
77 | SET @message_url = CONCAT(@url, N'editMessageText');
78 | SET @json_chat = JSON_MODIFY(@json_chat, '$.message_id', @message_id);
79 |
80 | EXEC [dbo].[usp_HttpPost]
81 | @url = @message_url,
82 | @headerXml = @http_headers,
83 | @requestBody = @json_chat,
84 | @success = @success OUTPUT,
85 | @response = @response OUTPUT,
86 | @error = @error OUTPUT;
87 |
88 | END
89 | ELSE
90 | BEGIN
91 |
92 | SET @message_url = CONCAT(@url, N'sendMessage');
93 |
94 | EXEC [dbo].[usp_HttpPost]
95 | @url = @message_url,
96 | @headerXml = @http_headers,
97 | @requestBody = @json_chat,
98 | @success = @success OUTPUT,
99 | @response = @response OUTPUT,
100 | @error = @error OUTPUT;
101 |
102 | SELECT TOP (1) @message_id = [message_id]
103 | FROM OPENJSON (@response, N'$.result')
104 | WITH
105 | (
106 | [message_id] nvarchar(max) N'$.message_id'
107 | );
108 |
109 | INSERT INTO [monitor].[progress]
110 | (
111 | [session_id]
112 | ,[message_id]
113 | ,[command]
114 | ,[database]
115 | ,[start_time]
116 | ,[estimated_completion_time]
117 | )
118 | VALUES
119 | (
120 | @session_id
121 | ,@message_id
122 | ,@command
123 | ,@database
124 | ,@start_time
125 | ,@estimated_completion_time
126 | );
127 |
128 | END;
129 |
130 | END;
131 |
132 | CLOSE [cur_progress];
133 | DEALLOCATE [cur_progress];
134 |
135 | DECLARE [cur_complete] CURSOR LOCAL FAST_FORWARD FOR
136 | SELECT
137 | [p].[session_id]
138 | ,[p].[message_id]
139 | ,[p].[command]
140 | ,[p].[database]
141 | ,[p].[start_time]
142 | ,[p].[estimated_completion_time]
143 | FROM [monitor].[progress] [p]
144 | LEFT JOIN [#t_progress] [t] ON [t].[session_id] = [p].[session_id]
145 | WHERE [t].[session_id] IS NULL
146 |
147 | OPEN [cur_complete];
148 |
149 | WHILE 1 = 1
150 | BEGIN
151 | FETCH NEXT FROM [cur_complete] INTO @session_id, @message_id, @command, @database, @start_time, @estimated_completion_time
152 | IF @@FETCH_STATUS <> 0 BREAK;
153 |
154 | SET @message_url = CONCAT(@url, N'editMessageText');
155 | SET @message = CONCAT(
156 | N'Сессия: ' + CONVERT(nvarchar(20), @session_id) + CHAR(10)
157 | ,N'База: ' + @database + CHAR(10)
158 | ,N'Команда: ' + @command + CHAR(10)
159 | ,N'Время начала: ' + CONVERT(nvarchar(50), @start_time, 120) + CHAR(10)
160 | ,N'Прогнозируемое время завершения: ' + CONVERT(nvarchar(50), @estimated_completion_time, 120) + CHAR(10)
161 | ,REPLICATE(N'▓', 10), N'100%' + CHAR(10)
162 | );
163 | SET @json_chat = N'{}';
164 | SET @json_chat = JSON_MODIFY(@json_chat, '$.text', @message);
165 | SET @json_chat = JSON_MODIFY(@json_chat, '$.chat_id', @chat_id);
166 | SET @json_chat = JSON_MODIFY(@json_chat, '$.message_id', @message_id);
167 |
168 | EXEC [dbo].[usp_HttpPost]
169 | @url = @message_url,
170 | @headerXml = @http_headers,
171 | @requestBody = @json_chat,
172 | @success = @success OUTPUT,
173 | @response = @response OUTPUT,
174 | @error = @error OUTPUT;
175 |
176 | DELETE
177 | FROM [monitor].[progress]
178 | WHERE [session_id] = @session_id;
179 |
180 | END;
181 |
182 | CLOSE [cur_complete];
183 | DEALLOCATE [cur_complete];
184 |
185 | END;
--------------------------------------------------------------------------------
/SqlTelegram/CLR/HttpLayer.cs:
--------------------------------------------------------------------------------
1 | using System;
2 | using System.Collections.Generic;
3 | using System.IO;
4 | using System.Net;
5 | using System.Text;
6 |
7 | namespace SqlTelegram
8 | {
9 | internal class HttpLayer
10 | {
11 | private const string telegram_url = "https://api.telegram.org/bot";
12 |
13 | public static HttpResult Get(
14 | string url,
15 | IEnumerable> headers)
16 | {
17 | HttpResult httpResult = new HttpResult();
18 | if (string.IsNullOrEmpty(url))
19 | {
20 | httpResult.Error = httpResult.ErrorMessage = "Invalid URL";
21 | return httpResult;
22 | }
23 | try
24 | {
25 | url = String.Concat(telegram_url, url);
26 | ServicePointManager.Expect100Continue = true;
27 | ServicePointManager.SecurityProtocol = SecurityProtocolType.Ssl3 | SecurityProtocolType.Tls12 | SecurityProtocolType.Tls11 | SecurityProtocolType.Tls;
28 | HttpWebRequest req = (HttpWebRequest)WebRequest.Create(url);
29 | req.Method = "GET";
30 | HttpLayer.AddHeaders(req, headers);
31 | HttpWebResponse response = (HttpWebResponse)req.GetResponse();
32 | using (StreamReader streamReader = new StreamReader(response.GetResponseStream()))
33 | httpResult.Response = streamReader.ReadToEnd();
34 | httpResult.Success = response.StatusCode == HttpStatusCode.OK || response.StatusCode == HttpStatusCode.Accepted;
35 | }
36 | catch (Exception ex)
37 | {
38 | httpResult.ErrorMessage = ex.Message;
39 | httpResult.Error = ex.ToString();
40 | }
41 | return httpResult;
42 | }
43 |
44 | public static HttpResult Post(
45 | string url,
46 | IEnumerable> headers,
47 | string requestBody)
48 | {
49 | HttpResult httpResult = new HttpResult();
50 | if (string.IsNullOrEmpty(url))
51 | {
52 | httpResult.Error = httpResult.ErrorMessage = "Invalid URL";
53 | return httpResult;
54 | }
55 | try
56 | {
57 | url = String.Concat(telegram_url, url);
58 | ServicePointManager.Expect100Continue = true;
59 | ServicePointManager.SecurityProtocol = SecurityProtocolType.Ssl3 | SecurityProtocolType.Tls12 | SecurityProtocolType.Tls11 | SecurityProtocolType.Tls;
60 | HttpWebRequest req = (HttpWebRequest)WebRequest.Create(url);
61 | req.Method = "POST";
62 | HttpLayer.AddHeaders(req, headers);
63 | if (!string.IsNullOrEmpty(requestBody))
64 | {
65 | byte[] bytes = Encoding.UTF8.GetBytes(requestBody);
66 | req.ContentLength = bytes.Length;
67 | using (Stream streamWriter = req.GetRequestStream())
68 | {
69 | streamWriter.Write(bytes, 0, bytes.Length);
70 | streamWriter.Flush();
71 | streamWriter.Close();
72 | }
73 | }
74 | else
75 | req.ContentLength = 0L;
76 | HttpWebResponse response = (HttpWebResponse)req.GetResponse();
77 | using (StreamReader streamReader = new StreamReader(response.GetResponseStream()))
78 | httpResult.Response = streamReader.ReadToEnd();
79 | httpResult.Success = response.StatusCode == HttpStatusCode.OK || response.StatusCode == HttpStatusCode.Accepted;
80 | }
81 | catch (Exception ex)
82 | {
83 | httpResult.ErrorMessage = ex.Message;
84 | httpResult.Error = ex.ToString();
85 | }
86 | return httpResult;
87 | }
88 |
89 | private static void AddHeaders(
90 | HttpWebRequest req,
91 | IEnumerable> headers)
92 | {
93 | if (headers == null)
94 | return;
95 | foreach (KeyValuePair header in headers)
96 | {
97 | string key = header.Key;
98 | string s = header.Value;
99 | if (WebHeaderCollection.IsRestricted(key))
100 | {
101 | switch (header.Key)
102 | {
103 | case "Accept":
104 | req.Accept = s;
105 | continue;
106 | case "Connection":
107 | req.Connection = s;
108 | continue;
109 | case "Content-Length":
110 | req.ContentLength = long.Parse(s);
111 | continue;
112 | case "Content-Type":
113 | req.ContentType = s;
114 | continue;
115 | case "Date":
116 | req.Date = DateTime.Parse(s);
117 | continue;
118 | case "Expect":
119 | req.Expect = s;
120 | continue;
121 | case "Host":
122 | req.Host = s;
123 | continue;
124 | case "If-Modified-Since":
125 | req.IfModifiedSince = DateTime.Parse(s);
126 | continue;
127 | case "Referer":
128 | req.Referer = s;
129 | continue;
130 | case "Transfer-Encoding":
131 | req.TransferEncoding = s;
132 | continue;
133 | case "User-Agent":
134 | req.UserAgent = s;
135 | continue;
136 | case "Range":
137 | throw new ApplicationException("Range header is not supported.");
138 | case "Proxy-Connection":
139 | throw new ApplicationException("Proxy-Connection header is not supported.");
140 | default:
141 | continue;
142 | }
143 | }
144 | else
145 | req.Headers.Add(key, s);
146 | }
147 | }
148 | }
149 | }
150 |
--------------------------------------------------------------------------------
/Jobs.sql:
--------------------------------------------------------------------------------
1 | USE [msdb]
2 | GO
3 |
4 | BEGIN TRANSACTION
5 | DECLARE @ReturnCode INT
6 | SELECT @ReturnCode = 0
7 |
8 | IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'[Uncategorized (Local)]' AND category_class=1)
9 | BEGIN
10 | EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'[Uncategorized (Local)]'
11 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
12 |
13 | END
14 |
15 | DECLARE @jobId BINARY(16)
16 | EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'tel_get_chat_updates',
17 | @enabled=1,
18 | @notify_level_eventlog=0,
19 | @notify_level_email=0,
20 | @notify_level_netsend=0,
21 | @notify_level_page=0,
22 | @delete_level=0,
23 | @description=N'No description available.',
24 | @category_name=N'[Uncategorized (Local)]',
25 | @owner_login_name=N'sa', @job_id = @jobId OUTPUT
26 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
27 | EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'st_get_chat_updates',
28 | @step_id=1,
29 | @cmdexec_success_code=0,
30 | @on_success_action=1,
31 | @on_success_step_id=0,
32 | @on_fail_action=2,
33 | @on_fail_step_id=0,
34 | @retry_attempts=0,
35 | @retry_interval=0,
36 | @os_run_priority=0, @subsystem=N'TSQL',
37 | @command=N'EXEC [dbo].[usp_get_chat_updates]',
38 | @database_name=N'telegram',
39 | @flags=0
40 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
41 | EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
42 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
43 | EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'sch_tel_get_chat_updates',
44 | @enabled=1,
45 | @freq_type=4,
46 | @freq_interval=1,
47 | @freq_subday_type=2,
48 | @freq_subday_interval=10,
49 | @freq_relative_interval=0,
50 | @freq_recurrence_factor=0,
51 | @active_start_date=20200915,
52 | @active_end_date=99991231,
53 | @active_start_time=0,
54 | @active_end_time=235959,
55 | @schedule_uid=N'f59a334a-cfbb-4541-874e-a58d679c9bad'
56 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
57 | EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
58 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
59 | COMMIT TRANSACTION
60 | GOTO EndSave
61 | QuitWithRollback:
62 | IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
63 | EndSave:
64 | GO
65 |
66 |
67 | BEGIN TRANSACTION
68 | DECLARE @ReturnCode INT
69 | SELECT @ReturnCode = 0
70 |
71 | IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'[Uncategorized (Local)]' AND category_class=1)
72 | BEGIN
73 | EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'[Uncategorized (Local)]'
74 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
75 |
76 | END
77 |
78 | DECLARE @jobId BINARY(16)
79 | EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'tel_monitor_progress',
80 | @enabled=1,
81 | @notify_level_eventlog=0,
82 | @notify_level_email=0,
83 | @notify_level_netsend=0,
84 | @notify_level_page=0,
85 | @delete_level=0,
86 | @description=N'No description available.',
87 | @category_name=N'[Uncategorized (Local)]',
88 | @owner_login_name=N'sa', @job_id = @jobId OUTPUT
89 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
90 | EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'st_monitor_progress',
91 | @step_id=1,
92 | @cmdexec_success_code=0,
93 | @on_success_action=1,
94 | @on_success_step_id=0,
95 | @on_fail_action=2,
96 | @on_fail_step_id=0,
97 | @retry_attempts=0,
98 | @retry_interval=0,
99 | @os_run_priority=0, @subsystem=N'TSQL',
100 | @command=N'EXEC [monitor].[usp_get_progress];
101 | ',
102 | @database_name=N'telegram',
103 | @flags=0
104 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
105 | EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
106 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
107 | EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'sch_monitor_progress',
108 | @enabled=1,
109 | @freq_type=4,
110 | @freq_interval=1,
111 | @freq_subday_type=2,
112 | @freq_subday_interval=10,
113 | @freq_relative_interval=0,
114 | @freq_recurrence_factor=0,
115 | @active_start_date=20200915,
116 | @active_end_date=99991231,
117 | @active_start_time=0,
118 | @active_end_time=235959,
119 | @schedule_uid=N'e5f7fd16-f794-44e6-ac88-1d4d6b54ac6d'
120 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
121 | EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
122 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
123 | COMMIT TRANSACTION
124 | GOTO EndSave
125 | QuitWithRollback:
126 | IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
127 | EndSave:
128 | GO
129 |
130 |
131 | BEGIN TRANSACTION
132 | DECLARE @ReturnCode INT
133 | SELECT @ReturnCode = 0
134 |
135 | IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'[Uncategorized (Local)]' AND category_class=1)
136 | BEGIN
137 | EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'[Uncategorized (Local)]'
138 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
139 |
140 | END
141 |
142 | DECLARE @jobId BINARY(16)
143 | EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'tel_monitoring',
144 | @enabled=1,
145 | @notify_level_eventlog=0,
146 | @notify_level_email=0,
147 | @notify_level_netsend=0,
148 | @notify_level_page=0,
149 | @delete_level=0,
150 | @description=N'No description available.',
151 | @category_name=N'[Uncategorized (Local)]',
152 | @owner_login_name=N'sa', @job_id = @jobId OUTPUT
153 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
154 | EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'st_tel_monitoring',
155 | @step_id=1,
156 | @cmdexec_success_code=0,
157 | @on_success_action=1,
158 | @on_success_step_id=0,
159 | @on_fail_action=2,
160 | @on_fail_step_id=0,
161 | @retry_attempts=0,
162 | @retry_interval=0,
163 | @os_run_priority=0, @subsystem=N'TSQL',
164 | @command=N'EXEC [monitor].[usp_check_cpu_usage]
165 | EXEC [monitor].[usp_check_disk_free_space]
166 | EXEC [monitor].[usp_check_disk_latency]
167 | EXEC [monitor].[usp_check_job_failed]
168 | EXEC [monitor].[usp_check_lock_wait]',
169 | @database_name=N'telegram',
170 | @flags=0
171 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
172 | EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
173 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
174 | EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'sch_tel_monitorings',
175 | @enabled=1,
176 | @freq_type=4,
177 | @freq_interval=1,
178 | @freq_subday_type=2,
179 | @freq_subday_interval=10,
180 | @freq_relative_interval=0,
181 | @freq_recurrence_factor=0,
182 | @active_start_date=20201002,
183 | @active_end_date=99991231,
184 | @active_start_time=0,
185 | @active_end_time=235959,
186 | @schedule_uid=N'ad15cc9e-d0bc-4d80-9f1f-b6036244a07c'
187 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
188 | EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
189 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
190 | COMMIT TRANSACTION
191 | GOTO EndSave
192 | QuitWithRollback:
193 | IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
194 | EndSave:
195 | GO
196 |
197 |
--------------------------------------------------------------------------------
/SqlTelegram/CLR/ClrHttp.cs:
--------------------------------------------------------------------------------
1 | using Microsoft.SqlServer.Server;
2 | using System;
3 | using System.Data;
4 | using System.Data.SqlClient;
5 | using System.Data.SqlTypes;
6 | using System.Collections.Generic;
7 | using System.Xml;
8 | using Newtonsoft.Json;
9 | using Newtonsoft.Json.Linq;
10 | using System.Security;
11 |
12 | namespace SqlTelegram
13 | {
14 | public class ClrHttp
15 | {
16 | [SqlProcedure]
17 | public static void HttpGet(
18 | SqlString url,
19 | SqlXml headerXml,
20 | out SqlBoolean success,
21 | out SqlString response,
22 | out SqlString error)
23 | {
24 | List> headers = GetHeaders(headerXml);
25 | var httpResult = HttpLayer.Get(url.IsNull ? (string)null : url.Value, (IEnumerable>)headers);
26 | success = (SqlBoolean)httpResult.Success;
27 | response = (SqlString)httpResult.Response;
28 | error = (SqlString)httpResult.Error;
29 | }
30 |
31 | [SqlProcedure]
32 | public static void HttpPost(
33 | SqlString url,
34 | SqlXml headerXml,
35 | SqlString requestBody,
36 | out SqlBoolean success,
37 | out SqlString response,
38 | out SqlString error)
39 | {
40 | List> headers = ClrHttp.GetHeaders(headerXml);
41 | string url1 = url.IsNull ? (string)null : url.Value;
42 | string requestBody1 = requestBody.IsNull ? (string)null : requestBody.Value;
43 | var httpResult = HttpLayer.Post(url1, (IEnumerable>)headers, requestBody1);
44 | success = (SqlBoolean)httpResult.Success;
45 | response = (SqlString)httpResult.Response;
46 | error = (SqlString)httpResult.Error;
47 | }
48 |
49 | [SqlProcedure]
50 | public static void Message2Command(
51 | SqlString json,
52 | SqlString bot_name,
53 | SqlString chat_id,
54 | out SqlString response)
55 | {
56 |
57 | string result = "";
58 | string variable = "";
59 |
60 | response = (SqlString)"";
61 | Dictionary obj = JObject.FromObject(JsonConvert.DeserializeObject(json.ToString())).ToObject>();
62 |
63 | JArray replies = (JArray)obj["result"];
64 |
65 | foreach (JToken reply in replies)
66 | {
67 |
68 | Dictionary dreply = JObject.FromObject(reply).ToObject>();
69 |
70 | if (dreply.ContainsKey("message"))
71 | {
72 | Dictionary message = JObject.FromObject(dreply["message"]).ToObject>();
73 | Dictionary chat = JObject.FromObject(message["chat"]).ToObject>();
74 | if (message.ContainsKey("entities") & chat["id"].ToString()==chat_id.ToString())
75 | {
76 | string text = message["text"].ToString(); //get command
77 | JArray entities = (JArray)message["entities"];
78 | foreach (JToken elm in entities)
79 | {
80 | if (elm["type"].ToString() == "bot_command")
81 | {
82 | string command = text.Substring((int)elm["offset"], (int)elm["length"]);
83 | if (command.Split('@')[1] == bot_name.ToString())
84 | {
85 | result = command.Split('@')[0].Substring(1);
86 | if (text.Split(' ').Length>1) variable = text.Split(' ')[1]; //get variable to pass to command
87 | break;
88 | }
89 |
90 | }
91 |
92 | }
93 | }
94 |
95 | }
96 | }
97 | if (result != "")
98 | {
99 | SqlString txt_query = "";
100 | SqlString columns_width = "";
101 |
102 | try
103 | {
104 | using (SqlConnection connection = new SqlConnection("context connection=true"))
105 | {
106 | connection.Open();
107 | //SqlCommand sqlCommand = new SqlCommand("SELECT [query] FROM [dbo].[commands] WHERE [command] = @command", connection);
108 | //sqlCommand.Parameters.AddWithValue("@command", result);
109 | //txt_query = (SqlString)(string)sqlCommand.ExecuteScalar();
110 |
111 | SqlCommand sqlCommand = new SqlCommand("SELECT [query], [columns_width] FROM [dbo].[commands] WHERE [command] = @command", connection);
112 |
113 | sqlCommand.Parameters.AddWithValue("@command", result);
114 | SqlDataReader reader = sqlCommand.ExecuteReader();
115 | while (reader.Read())
116 | {
117 | txt_query = reader["query"].ToString();
118 | columns_width = reader["columns_width"].ToString();
119 | }
120 | reader.Close();
121 | }
122 | if (txt_query != "")
123 | {
124 | SQL2string(txt_query, variable, 10, 6, 10, columns_width, out response);
125 | }
126 | }
127 | catch { }
128 | }
129 | }
130 |
131 | [SqlProcedure]
132 | public static void SQL2string(
133 | SqlString txt_query,
134 | String variable,
135 | int num_rows,
136 | int num_cols,
137 | int col_width,
138 | SqlString list_width,
139 | out SqlString response)
140 | {
141 |
142 | bool cw = list_width.ToString().Length > 0;
143 |
144 | List widths = new List();
145 |
146 | if (cw)
147 | {
148 | widths = new List(Array.ConvertAll(list_width.ToString().Split(','), int.Parse));
149 | }
150 |
151 | string crn = "+", ln = "-", cl = "|",
152 | nl = System.Environment.NewLine;
153 | string result = "```" + nl;
154 |
155 | int col_counter = 0, row_counter = 0;
156 |
157 |
158 | //Get the select results
159 | var dt = new DataTable();
160 | using (var con = OpenContextConnection())
161 | {
162 | try
163 | {
164 | var cmd = new SqlCommand(txt_query.ToString(), con);
165 | if (variable.Trim().Length > 0) cmd.Parameters.AddWithValue("@param",variable);
166 |
167 | SqlContext.Pipe.Send("SQL Command:" + cmd.CommandText.ToString());
168 | SqlContext.Pipe.Send("Parameter Value:" + cmd.Parameters[0].Value.ToString());
169 |
170 | var da = new SqlDataAdapter(cmd);
171 | da.Fill(dt);
172 |
173 | SqlContext.Pipe.Send("Rows returned:" + dt.Rows.Count.ToString());
174 | SqlContext.Pipe.Send("First Value:" + dt.Rows[0].ItemArray[0].ToString());
175 | }
176 | catch (Exception e)
177 | {
178 | SqlContext.Pipe.Send(e.Message);
179 | }
180 | }
181 |
182 | try
183 | {
184 | SqlContext.Pipe.Send("Separator");
185 | // construct line separator
186 | var lin_sep = crn;
187 | foreach (DataColumn col in dt.Columns)
188 | {
189 | SqlContext.Pipe.Send("Column Name:" + col.ToString());
190 | int wd = cw ? widths[col_counter] : col_width;
191 | lin_sep += new String(ln.ToCharArray()[0], wd) + crn;
192 | col_counter++;
193 | if (col_counter > num_cols) break;
194 | }
195 | //lin_sep += nl;
196 |
197 | SqlContext.Pipe.Send("Header");
198 | // Construct the header
199 | result += cl;
200 | col_counter = 0;
201 | foreach (DataColumn col in dt.Columns)
202 | {
203 | int wd = cw ? widths[col_counter] : col_width;
204 | result += FormatString(col.ColumnName, wd) + cl;
205 | col_counter++;
206 | if (col_counter > num_cols) break;
207 | }
208 | result += nl + lin_sep;
209 |
210 | SqlContext.Pipe.Send("Body");
211 | // Construct the body
212 | foreach (DataRow row in dt.Rows)
213 | {
214 | col_counter = 0;
215 | result += nl + cl;
216 | foreach (DataColumn col in dt.Columns)
217 | {
218 | int wd = cw ? widths[col_counter] : col_width;
219 | result += FormatString(row[col.ColumnName].ToString(), wd) + cl;
220 | col_counter++;
221 | if (col_counter > num_cols) break;
222 | }
223 |
224 | row_counter++;
225 | if (row_counter > num_rows) break;
226 |
227 | }
228 |
229 | result += nl + "```";
230 |
231 | SqlContext.Pipe.Send("Formated output:" + result);
232 | }
233 | catch (Exception e)
234 | {
235 | SqlContext.Pipe.Send("ERROR");
236 | SqlContext.Pipe.Send("MESSAGE\n" + e.Message);
237 | SqlContext.Pipe.Send("STACK TRACE \n" + e.StackTrace);
238 | }
239 |
240 | response = result;
241 | }
242 |
243 | static SqlConnection OpenContextConnection()
244 | {
245 | SqlConnection connection = new SqlConnection("context connection=true");
246 | connection.Open();
247 | return connection;
248 | }
249 |
250 | static string FormatString(string str, int len = 10)
251 | {
252 | string cont = ">";
253 |
254 | if (str.Length > len)
255 | {
256 | return str.Substring(0, len - 1) + cont;
257 | }
258 | else
259 | {
260 | return str + new String(' ', len - str.Length);
261 | }
262 |
263 | }
264 |
265 | private static List> GetHeaders(SqlXml headerXml)
266 | {
267 | List> keyValuePairList = (List>)null;
268 | if (headerXml != null && !headerXml.IsNull)
269 | {
270 | keyValuePairList = new List>();
271 | using (XmlReader reader = headerXml.CreateReader())
272 | {
273 | while (reader.Read())
274 | {
275 | if (reader.NodeType == XmlNodeType.Element && reader.Name == "Header")
276 | {
277 | string attribute1 = reader.GetAttribute("Name");
278 | string attribute2 = reader.GetAttribute("Value");
279 | keyValuePairList.Add(new KeyValuePair(attribute1, attribute2));
280 | }
281 | }
282 | }
283 | }
284 | return keyValuePairList;
285 | }
286 | }
287 | }
288 |
--------------------------------------------------------------------------------
/SqlTelegram/SqlTelegram.sqlproj:
--------------------------------------------------------------------------------
1 |
2 |
3 |
4 |
5 | Debug
6 | AnyCPU
7 | SqlTelegram
8 | 2.0
9 | 4.1
10 | {e493f856-7bb1-4a96-87cc-d3ff25f458f1}
11 | Microsoft.Data.Tools.Schema.Sql.Sql140DatabaseSchemaProvider
12 | Database
13 |
14 |
15 | SqlTelegram
16 | SqlTelegram
17 | 1033, CI
18 | BySchemaAndSchemaType
19 | True
20 | v4.5
21 | CS
22 | Properties
23 | False
24 | True
25 | True
26 | UNSAFE
27 |
28 |
29 | bin\Release\
30 | $(MSBuildProjectName).sql
31 | False
32 | pdbonly
33 | true
34 | false
35 | true
36 | prompt
37 | 4
38 |
39 |
40 | bin\Debug\
41 | $(MSBuildProjectName).sql
42 | false
43 | true
44 | full
45 | false
46 | true
47 | true
48 | prompt
49 | 4
50 |
51 |
52 | 11.0
53 |
54 | True
55 | 11.0
56 |
57 |
58 |
59 |
60 |
61 |
62 |
63 |
64 |
65 |
66 |
67 |
68 |
69 |
70 |
71 |
72 |
73 |
74 |
75 |
76 |
77 |
78 | ..\..\..\..\source\repos\SQL_telegram\SqlTelegram\dlls\Newtonsoft.Json.dll
79 |
80 |
81 | Assemblies\System.Runtime.Serialization.Formatters.Soap.dll
82 | System.Runtime.Serialization.Formatters.Soap
83 | True
84 | False
85 | dbo
86 | UNSAFE
87 | False
88 |
89 |
90 | Assemblies\System.Drawing.dll
91 | System.Drawing
92 | True
93 | False
94 | dbo
95 | UNSAFE
96 | False
97 |
98 |
99 | Assemblies\System.DirectoryServices.dll
100 | System.DirectoryServices
101 | True
102 | False
103 | dbo
104 | UNSAFE
105 | False
106 |
107 |
108 | Assemblies\Accessibility.dll
109 | Accessibility
110 | True
111 | False
112 | dbo
113 | UNSAFE
114 | False
115 |
116 |
117 | Assemblies\System_2.Windows.Forms.dll
118 | System.Windows.Forms
119 | True
120 | False
121 | dbo
122 | UNSAFE
123 | False
124 |
125 |
126 | Assemblies\System_2.ServiceModel.Internals.dll
127 | System.ServiceModel.Internals
128 | True
129 | False
130 | dbo
131 | UNSAFE
132 | False
133 |
134 |
135 | Assemblies\System_2.Runtime.Serialization.dll
136 | System.Runtime.Serialization
137 | True
138 | False
139 | dbo
140 | UNSAFE
141 | False
142 |
143 |
144 | Assemblies\System.Messaging.dll
145 | System.Messaging
146 | True
147 | False
148 | dbo
149 | UNSAFE
150 |
151 |
152 | Assemblies\System.Configuration.Install.dll
153 | System.Configuration.Install
154 | True
155 | False
156 | dbo
157 | UNSAFE
158 | False
159 |
160 |
161 | Assemblies\SMDiagnostics_2.dll
162 | SMDiagnostics
163 | True
164 | False
165 | dbo
166 | UNSAFE
167 | False
168 |
169 |
170 | Assemblies\SqlTelegram_1.dll
171 | SqlTelegram
172 | True
173 | False
174 | dbo
175 | UNSAFE
176 |
177 |
178 |
179 |
180 |
181 |
182 |
183 |
184 |
185 |
186 |
187 |
188 |
189 |
190 |
191 |
192 |
193 |
194 |
195 |
196 |
197 |
198 |
199 |
200 |
201 |
202 |
203 |
204 |
205 |
206 |
207 |
208 |
209 |
210 |
211 |
212 |
213 |
214 |
215 |
216 |
217 |
218 |
219 |
220 |
221 |
222 |
223 |
224 |
225 |
226 |
227 |
228 |
229 |
230 |
231 |
232 |
233 |
--------------------------------------------------------------------------------
/LICENSE:
--------------------------------------------------------------------------------
1 | Attribution-NonCommercial-ShareAlike 4.0 International
2 |
3 | =======================================================================
4 |
5 | Creative Commons Corporation ("Creative Commons") is not a law firm and
6 | does not provide legal services or legal advice. Distribution of
7 | Creative Commons public licenses does not create a lawyer-client or
8 | other relationship. Creative Commons makes its licenses and related
9 | information available on an "as-is" basis. Creative Commons gives no
10 | warranties regarding its licenses, any material licensed under their
11 | terms and conditions, or any related information. Creative Commons
12 | disclaims all liability for damages resulting from their use to the
13 | fullest extent possible.
14 |
15 | Using Creative Commons Public Licenses
16 |
17 | Creative Commons public licenses provide a standard set of terms and
18 | conditions that creators and other rights holders may use to share
19 | original works of authorship and other material subject to copyright
20 | and certain other rights specified in the public license below. The
21 | following considerations are for informational purposes only, are not
22 | exhaustive, and do not form part of our licenses.
23 |
24 | Considerations for licensors: Our public licenses are
25 | intended for use by those authorized to give the public
26 | permission to use material in ways otherwise restricted by
27 | copyright and certain other rights. Our licenses are
28 | irrevocable. Licensors should read and understand the terms
29 | and conditions of the license they choose before applying it.
30 | Licensors should also secure all rights necessary before
31 | applying our licenses so that the public can reuse the
32 | material as expected. Licensors should clearly mark any
33 | material not subject to the license. This includes other CC-
34 | licensed material, or material used under an exception or
35 | limitation to copyright. More considerations for licensors:
36 | wiki.creativecommons.org/Considerations_for_licensors
37 |
38 | Considerations for the public: By using one of our public
39 | licenses, a licensor grants the public permission to use the
40 | licensed material under specified terms and conditions. If
41 | the licensor's permission is not necessary for any reason--for
42 | example, because of any applicable exception or limitation to
43 | copyright--then that use is not regulated by the license. Our
44 | licenses grant only permissions under copyright and certain
45 | other rights that a licensor has authority to grant. Use of
46 | the licensed material may still be restricted for other
47 | reasons, including because others have copyright or other
48 | rights in the material. A licensor may make special requests,
49 | such as asking that all changes be marked or described.
50 | Although not required by our licenses, you are encouraged to
51 | respect those requests where reasonable. More_considerations
52 | for the public:
53 | wiki.creativecommons.org/Considerations_for_licensees
54 |
55 | =======================================================================
56 |
57 | Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International
58 | Public License
59 |
60 | By exercising the Licensed Rights (defined below), You accept and agree
61 | to be bound by the terms and conditions of this Creative Commons
62 | Attribution-NonCommercial-ShareAlike 4.0 International Public License
63 | ("Public License"). To the extent this Public License may be
64 | interpreted as a contract, You are granted the Licensed Rights in
65 | consideration of Your acceptance of these terms and conditions, and the
66 | Licensor grants You such rights in consideration of benefits the
67 | Licensor receives from making the Licensed Material available under
68 | these terms and conditions.
69 |
70 |
71 | Section 1 -- Definitions.
72 |
73 | a. Adapted Material means material subject to Copyright and Similar
74 | Rights that is derived from or based upon the Licensed Material
75 | and in which the Licensed Material is translated, altered,
76 | arranged, transformed, or otherwise modified in a manner requiring
77 | permission under the Copyright and Similar Rights held by the
78 | Licensor. For purposes of this Public License, where the Licensed
79 | Material is a musical work, performance, or sound recording,
80 | Adapted Material is always produced where the Licensed Material is
81 | synched in timed relation with a moving image.
82 |
83 | b. Adapter's License means the license You apply to Your Copyright
84 | and Similar Rights in Your contributions to Adapted Material in
85 | accordance with the terms and conditions of this Public License.
86 |
87 | c. BY-NC-SA Compatible License means a license listed at
88 | creativecommons.org/compatiblelicenses, approved by Creative
89 | Commons as essentially the equivalent of this Public License.
90 |
91 | d. Copyright and Similar Rights means copyright and/or similar rights
92 | closely related to copyright including, without limitation,
93 | performance, broadcast, sound recording, and Sui Generis Database
94 | Rights, without regard to how the rights are labeled or
95 | categorized. For purposes of this Public License, the rights
96 | specified in Section 2(b)(1)-(2) are not Copyright and Similar
97 | Rights.
98 |
99 | e. Effective Technological Measures means those measures that, in the
100 | absence of proper authority, may not be circumvented under laws
101 | fulfilling obligations under Article 11 of the WIPO Copyright
102 | Treaty adopted on December 20, 1996, and/or similar international
103 | agreements.
104 |
105 | f. Exceptions and Limitations means fair use, fair dealing, and/or
106 | any other exception or limitation to Copyright and Similar Rights
107 | that applies to Your use of the Licensed Material.
108 |
109 | g. License Elements means the license attributes listed in the name
110 | of a Creative Commons Public License. The License Elements of this
111 | Public License are Attribution, NonCommercial, and ShareAlike.
112 |
113 | h. Licensed Material means the artistic or literary work, database,
114 | or other material to which the Licensor applied this Public
115 | License.
116 |
117 | i. Licensed Rights means the rights granted to You subject to the
118 | terms and conditions of this Public License, which are limited to
119 | all Copyright and Similar Rights that apply to Your use of the
120 | Licensed Material and that the Licensor has authority to license.
121 |
122 | j. Licensor means the individual(s) or entity(ies) granting rights
123 | under this Public License.
124 |
125 | k. NonCommercial means not primarily intended for or directed towards
126 | commercial advantage or monetary compensation. For purposes of
127 | this Public License, the exchange of the Licensed Material for
128 | other material subject to Copyright and Similar Rights by digital
129 | file-sharing or similar means is NonCommercial provided there is
130 | no payment of monetary compensation in connection with the
131 | exchange.
132 |
133 | l. Share means to provide material to the public by any means or
134 | process that requires permission under the Licensed Rights, such
135 | as reproduction, public display, public performance, distribution,
136 | dissemination, communication, or importation, and to make material
137 | available to the public including in ways that members of the
138 | public may access the material from a place and at a time
139 | individually chosen by them.
140 |
141 | m. Sui Generis Database Rights means rights other than copyright
142 | resulting from Directive 96/9/EC of the European Parliament and of
143 | the Council of 11 March 1996 on the legal protection of databases,
144 | as amended and/or succeeded, as well as other essentially
145 | equivalent rights anywhere in the world.
146 |
147 | n. You means the individual or entity exercising the Licensed Rights
148 | under this Public License. Your has a corresponding meaning.
149 |
150 |
151 | Section 2 -- Scope.
152 |
153 | a. License grant.
154 |
155 | 1. Subject to the terms and conditions of this Public License,
156 | the Licensor hereby grants You a worldwide, royalty-free,
157 | non-sublicensable, non-exclusive, irrevocable license to
158 | exercise the Licensed Rights in the Licensed Material to:
159 |
160 | a. reproduce and Share the Licensed Material, in whole or
161 | in part, for NonCommercial purposes only; and
162 |
163 | b. produce, reproduce, and Share Adapted Material for
164 | NonCommercial purposes only.
165 |
166 | 2. Exceptions and Limitations. For the avoidance of doubt, where
167 | Exceptions and Limitations apply to Your use, this Public
168 | License does not apply, and You do not need to comply with
169 | its terms and conditions.
170 |
171 | 3. Term. The term of this Public License is specified in Section
172 | 6(a).
173 |
174 | 4. Media and formats; technical modifications allowed. The
175 | Licensor authorizes You to exercise the Licensed Rights in
176 | all media and formats whether now known or hereafter created,
177 | and to make technical modifications necessary to do so. The
178 | Licensor waives and/or agrees not to assert any right or
179 | authority to forbid You from making technical modifications
180 | necessary to exercise the Licensed Rights, including
181 | technical modifications necessary to circumvent Effective
182 | Technological Measures. For purposes of this Public License,
183 | simply making modifications authorized by this Section 2(a)
184 | (4) never produces Adapted Material.
185 |
186 | 5. Downstream recipients.
187 |
188 | a. Offer from the Licensor -- Licensed Material. Every
189 | recipient of the Licensed Material automatically
190 | receives an offer from the Licensor to exercise the
191 | Licensed Rights under the terms and conditions of this
192 | Public License.
193 |
194 | b. Additional offer from the Licensor -- Adapted Material.
195 | Every recipient of Adapted Material from You
196 | automatically receives an offer from the Licensor to
197 | exercise the Licensed Rights in the Adapted Material
198 | under the conditions of the Adapter's License You apply.
199 |
200 | c. No downstream restrictions. You may not offer or impose
201 | any additional or different terms or conditions on, or
202 | apply any Effective Technological Measures to, the
203 | Licensed Material if doing so restricts exercise of the
204 | Licensed Rights by any recipient of the Licensed
205 | Material.
206 |
207 | 6. No endorsement. Nothing in this Public License constitutes or
208 | may be construed as permission to assert or imply that You
209 | are, or that Your use of the Licensed Material is, connected
210 | with, or sponsored, endorsed, or granted official status by,
211 | the Licensor or others designated to receive attribution as
212 | provided in Section 3(a)(1)(A)(i).
213 |
214 | b. Other rights.
215 |
216 | 1. Moral rights, such as the right of integrity, are not
217 | licensed under this Public License, nor are publicity,
218 | privacy, and/or other similar personality rights; however, to
219 | the extent possible, the Licensor waives and/or agrees not to
220 | assert any such rights held by the Licensor to the limited
221 | extent necessary to allow You to exercise the Licensed
222 | Rights, but not otherwise.
223 |
224 | 2. Patent and trademark rights are not licensed under this
225 | Public License.
226 |
227 | 3. To the extent possible, the Licensor waives any right to
228 | collect royalties from You for the exercise of the Licensed
229 | Rights, whether directly or through a collecting society
230 | under any voluntary or waivable statutory or compulsory
231 | licensing scheme. In all other cases the Licensor expressly
232 | reserves any right to collect such royalties, including when
233 | the Licensed Material is used other than for NonCommercial
234 | purposes.
235 |
236 |
237 | Section 3 -- License Conditions.
238 |
239 | Your exercise of the Licensed Rights is expressly made subject to the
240 | following conditions.
241 |
242 | a. Attribution.
243 |
244 | 1. If You Share the Licensed Material (including in modified
245 | form), You must:
246 |
247 | a. retain the following if it is supplied by the Licensor
248 | with the Licensed Material:
249 |
250 | i. identification of the creator(s) of the Licensed
251 | Material and any others designated to receive
252 | attribution, in any reasonable manner requested by
253 | the Licensor (including by pseudonym if
254 | designated);
255 |
256 | ii. a copyright notice;
257 |
258 | iii. a notice that refers to this Public License;
259 |
260 | iv. a notice that refers to the disclaimer of
261 | warranties;
262 |
263 | v. a URI or hyperlink to the Licensed Material to the
264 | extent reasonably practicable;
265 |
266 | b. indicate if You modified the Licensed Material and
267 | retain an indication of any previous modifications; and
268 |
269 | c. indicate the Licensed Material is licensed under this
270 | Public License, and include the text of, or the URI or
271 | hyperlink to, this Public License.
272 |
273 | 2. You may satisfy the conditions in Section 3(a)(1) in any
274 | reasonable manner based on the medium, means, and context in
275 | which You Share the Licensed Material. For example, it may be
276 | reasonable to satisfy the conditions by providing a URI or
277 | hyperlink to a resource that includes the required
278 | information.
279 | 3. If requested by the Licensor, You must remove any of the
280 | information required by Section 3(a)(1)(A) to the extent
281 | reasonably practicable.
282 |
283 | b. ShareAlike.
284 |
285 | In addition to the conditions in Section 3(a), if You Share
286 | Adapted Material You produce, the following conditions also apply.
287 |
288 | 1. The Adapter's License You apply must be a Creative Commons
289 | license with the same License Elements, this version or
290 | later, or a BY-NC-SA Compatible License.
291 |
292 | 2. You must include the text of, or the URI or hyperlink to, the
293 | Adapter's License You apply. You may satisfy this condition
294 | in any reasonable manner based on the medium, means, and
295 | context in which You Share Adapted Material.
296 |
297 | 3. You may not offer or impose any additional or different terms
298 | or conditions on, or apply any Effective Technological
299 | Measures to, Adapted Material that restrict exercise of the
300 | rights granted under the Adapter's License You apply.
301 |
302 |
303 | Section 4 -- Sui Generis Database Rights.
304 |
305 | Where the Licensed Rights include Sui Generis Database Rights that
306 | apply to Your use of the Licensed Material:
307 |
308 | a. for the avoidance of doubt, Section 2(a)(1) grants You the right
309 | to extract, reuse, reproduce, and Share all or a substantial
310 | portion of the contents of the database for NonCommercial purposes
311 | only;
312 |
313 | b. if You include all or a substantial portion of the database
314 | contents in a database in which You have Sui Generis Database
315 | Rights, then the database in which You have Sui Generis Database
316 | Rights (but not its individual contents) is Adapted Material,
317 | including for purposes of Section 3(b); and
318 |
319 | c. You must comply with the conditions in Section 3(a) if You Share
320 | all or a substantial portion of the contents of the database.
321 |
322 | For the avoidance of doubt, this Section 4 supplements and does not
323 | replace Your obligations under this Public License where the Licensed
324 | Rights include other Copyright and Similar Rights.
325 |
326 |
327 | Section 5 -- Disclaimer of Warranties and Limitation of Liability.
328 |
329 | a. UNLESS OTHERWISE SEPARATELY UNDERTAKEN BY THE LICENSOR, TO THE
330 | EXTENT POSSIBLE, THE LICENSOR OFFERS THE LICENSED MATERIAL AS-IS
331 | AND AS-AVAILABLE, AND MAKES NO REPRESENTATIONS OR WARRANTIES OF
332 | ANY KIND CONCERNING THE LICENSED MATERIAL, WHETHER EXPRESS,
333 | IMPLIED, STATUTORY, OR OTHER. THIS INCLUDES, WITHOUT LIMITATION,
334 | WARRANTIES OF TITLE, MERCHANTABILITY, FITNESS FOR A PARTICULAR
335 | PURPOSE, NON-INFRINGEMENT, ABSENCE OF LATENT OR OTHER DEFECTS,
336 | ACCURACY, OR THE PRESENCE OR ABSENCE OF ERRORS, WHETHER OR NOT
337 | KNOWN OR DISCOVERABLE. WHERE DISCLAIMERS OF WARRANTIES ARE NOT
338 | ALLOWED IN FULL OR IN PART, THIS DISCLAIMER MAY NOT APPLY TO YOU.
339 |
340 | b. TO THE EXTENT POSSIBLE, IN NO EVENT WILL THE LICENSOR BE LIABLE
341 | TO YOU ON ANY LEGAL THEORY (INCLUDING, WITHOUT LIMITATION,
342 | NEGLIGENCE) OR OTHERWISE FOR ANY DIRECT, SPECIAL, INDIRECT,
343 | INCIDENTAL, CONSEQUENTIAL, PUNITIVE, EXEMPLARY, OR OTHER LOSSES,
344 | COSTS, EXPENSES, OR DAMAGES ARISING OUT OF THIS PUBLIC LICENSE OR
345 | USE OF THE LICENSED MATERIAL, EVEN IF THE LICENSOR HAS BEEN
346 | ADVISED OF THE POSSIBILITY OF SUCH LOSSES, COSTS, EXPENSES, OR
347 | DAMAGES. WHERE A LIMITATION OF LIABILITY IS NOT ALLOWED IN FULL OR
348 | IN PART, THIS LIMITATION MAY NOT APPLY TO YOU.
349 |
350 | c. The disclaimer of warranties and limitation of liability provided
351 | above shall be interpreted in a manner that, to the extent
352 | possible, most closely approximates an absolute disclaimer and
353 | waiver of all liability.
354 |
355 |
356 | Section 6 -- Term and Termination.
357 |
358 | a. This Public License applies for the term of the Copyright and
359 | Similar Rights licensed here. However, if You fail to comply with
360 | this Public License, then Your rights under this Public License
361 | terminate automatically.
362 |
363 | b. Where Your right to use the Licensed Material has terminated under
364 | Section 6(a), it reinstates:
365 |
366 | 1. automatically as of the date the violation is cured, provided
367 | it is cured within 30 days of Your discovery of the
368 | violation; or
369 |
370 | 2. upon express reinstatement by the Licensor.
371 |
372 | For the avoidance of doubt, this Section 6(b) does not affect any
373 | right the Licensor may have to seek remedies for Your violations
374 | of this Public License.
375 |
376 | c. For the avoidance of doubt, the Licensor may also offer the
377 | Licensed Material under separate terms or conditions or stop
378 | distributing the Licensed Material at any time; however, doing so
379 | will not terminate this Public License.
380 |
381 | d. Sections 1, 5, 6, 7, and 8 survive termination of this Public
382 | License.
383 |
384 |
385 | Section 7 -- Other Terms and Conditions.
386 |
387 | a. The Licensor shall not be bound by any additional or different
388 | terms or conditions communicated by You unless expressly agreed.
389 |
390 | b. Any arrangements, understandings, or agreements regarding the
391 | Licensed Material not stated herein are separate from and
392 | independent of the terms and conditions of this Public License.
393 |
394 |
395 | Section 8 -- Interpretation.
396 |
397 | a. For the avoidance of doubt, this Public License does not, and
398 | shall not be interpreted to, reduce, limit, restrict, or impose
399 | conditions on any use of the Licensed Material that could lawfully
400 | be made without permission under this Public License.
401 |
402 | b. To the extent possible, if any provision of this Public License is
403 | deemed unenforceable, it shall be automatically reformed to the
404 | minimum extent necessary to make it enforceable. If the provision
405 | cannot be reformed, it shall be severed from this Public License
406 | without affecting the enforceability of the remaining terms and
407 | conditions.
408 |
409 | c. No term or condition of this Public License will be waived and no
410 | failure to comply consented to unless expressly agreed to by the
411 | Licensor.
412 |
413 | d. Nothing in this Public License constitutes or may be interpreted
414 | as a limitation upon, or waiver of, any privileges and immunities
415 | that apply to the Licensor or You, including from the legal
416 | processes of any jurisdiction or authority.
417 |
418 | =======================================================================
419 |
420 | Creative Commons is not a party to its public
421 | licenses. Notwithstanding, Creative Commons may elect to apply one of
422 | its public licenses to material it publishes and in those instances
423 | will be considered the “Licensor.” The text of the Creative Commons
424 | public licenses is dedicated to the public domain under the CC0 Public
425 | Domain Dedication. Except for the limited purpose of indicating that
426 | material is shared under a Creative Commons public license or as
427 | otherwise permitted by the Creative Commons policies published at
428 | creativecommons.org/policies, Creative Commons does not authorize the
429 | use of the trademark "Creative Commons" or any other trademark or logo
430 | of Creative Commons without its prior written consent including,
431 | without limitation, in connection with any unauthorized modifications
432 | to any of its public licenses or any other arrangements,
433 | understandings, or agreements concerning use of licensed material. For
434 | the avoidance of doubt, this paragraph does not form part of the
435 | public licenses.
436 |
437 | Creative Commons may be contacted at creativecommons.org.
438 |
--------------------------------------------------------------------------------