Skip to content

Commit

Permalink
v 0.6.1 Beta
Browse files Browse the repository at this point in the history
  • Loading branch information
yorek committed Aug 28, 2014
1 parent 34b729a commit 769fe65
Show file tree
Hide file tree
Showing 29 changed files with 622 additions and 357 deletions.
8 changes: 3 additions & 5 deletions .gitignore
Original file line number Diff line number Diff line change
Expand Up @@ -25,11 +25,9 @@ var/

# Visual Studio
ptvs_virtualenv_proxy.py
SSIS-Dashboard-Web-Client.pyproj
web.config
web.debug.config
Azure.pubxml
Web.ssis-dashboard.config
*.pyproj
*.pubxml
*.config

# Installer logs
pip-log.txt
Expand Down
36 changes: 23 additions & 13 deletions README.md
Original file line number Diff line number Diff line change
@@ -1,25 +1,35 @@
SQL Server Integration Services Dashboard
SQL Server Integration Services Dashboard v 0.6.1 Beta
=========================================

The purpose of this project is to provide a web-based, user-friendly, useful and nice looking SQL Server Integration Services Dashboard and a set of REST API to monitor execution of SQL Server Integration Services Packages.

An online working demo version is available here: http://ssis-dashboard.azurewebsites.net/

![v0 5 2](https://cloud.githubusercontent.com/assets/2612362/4003128/76e6869e-2973-11e4-9629-2bf45acd1141.png)
![Sample Screenshot](https://cloud.githubusercontent.com/assets/2612362/4003128/76e6869e-2973-11e4-9629-2bf45acd1141.png)

##Version
##Release Notes

v 0.5.2 Beta
###v 0.6.1 Beta

##Release Notes
* Updated Morris.js to v 0.5.1
* Updated MetisMenu to v 1.1.1
* Added information on "Child" Packages
* Added more detail to the "Package Execution History" page. Also added an estimated end time / elapsed time for running packages, using a moving average of 7 steps.
* Added navigation sidebar in the main page that shows available folders and projects
* Added support for folders and project filtering
* Changed configuration file in order to comply with Python/Flask standards
* Cleaned Up code in order to follow Python best pratices (still a lot to do :))

###v 0.5.2 Beta

v 0.5.2 Beta
Added support for "\*" wildcard in project names. Now you can filter a specific project name using an url like:
```
http://<yourserver>/project/MyPro*
```
Added initial support for Package Execution History. Just click on a package name and you'll see its latest 15 executions

v 0.4 Beta
###v 0.4 Beta

First public release

##Current Release
Expand All @@ -34,13 +44,13 @@ Priority has been put to the web interface. From the web interface the page with

##Roadmap

v 1.0
HTML5, Bootstrap-Based, Web Interface, directly querying database
REST API
##v 1.0
* HTML5, Bootstrap-Based, Web Interface, directly querying database
* REST API

V 1.1
Change Web Interface to use JQuery to invoke REST APIs to get data from DB.
Remove any direct query to the database from the website dashboard
##v 1.1
* Change Web Interface to use JQuery to invoke REST APIs to get data from DB.
* Remove any direct query to the database from the website dashboard

##Platforms & Tools

Expand Down
37 changes: 27 additions & 10 deletions app.py
Original file line number Diff line number Diff line change
@@ -1,22 +1,39 @@
from flask import Flask
"""
This script runs the application using a development server.
It contains the definition of routes and views for the application.
"""

# If you get an error on the next line on Python 3.4.0, change to: Flask('app')
# where app matches the name of this file without the .py extension.
from flask import Flask
app = Flask(__name__)

# Make the WSGI interface available at the top level so wfastcgi can get it.
wsgi_app = app.wsgi_app

# Configure App
import config
app.config.from_object(config)

# Import Modules
from routes import *
from processors import *
from filters import *

# Make the WSGI interface available at the top level so wfastcgi can get it.
wsgi_app = app

if __name__ == '__main__':
import os
host = os.environ.get('SERVER_HOST', 'localhost')
HOST = os.environ.get('SERVER_HOST', 'localhost')
try:
port = int(os.environ.get('SERVER_PORT', '5555'))
PORT = int(os.environ.get('SERVER_PORT', '5555'))
except ValueError:
port = 5555
app.run(host, port, threaded=True, debug=False)
PORT = 5555

if not app.debug:
import logging
from logging.handlers import RotatingFileHandler
from logging import Formatter
file_handler = RotatingFileHandler('app.log', maxBytes = 10240, backupCount = 3, encoding = 'utf-8')
file_handler.setLevel(logging.WARNING)
file_handler.setFormatter(Formatter('%(asctime)s %(levelname)s: %(message)s ''[in %(pathname)s:%(lineno)d]'))
app.logger.addHandler(file_handler)

app.run(HOST, PORT, threaded=True)

4 changes: 4 additions & 0 deletions config.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
AZURE = False
DEBUG = True
CONNECTION_STRING = "DRIVER={SQL Server};SERVER=localhost;DATABASE=SSISDB;UID=dm;PWD=Passw0rd!"
HOUR_SPAN = 720
4 changes: 0 additions & 4 deletions config.txt

This file was deleted.

13 changes: 0 additions & 13 deletions configuration.py

This file was deleted.

9 changes: 8 additions & 1 deletion filters.py
Original file line number Diff line number Diff line change
Expand Up @@ -4,5 +4,12 @@
def project(text):
result = ''
if (text != 'all'):
result = ' "' + text + '"'
result = ' for "' + text + '"'
return result

@app.template_filter('folder')
def folder(text):
result = ''
if (text != 'all'):
result = ' in "' + text + '"'
return result
1 change: 1 addition & 0 deletions query/engine-folders.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
SELECT folder_id, name, [description] FROM [catalog].folders
3 changes: 3 additions & 0 deletions query/engine-kpi.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,5 @@
DECLARE @hourspan INT = ?;
DECLARE @folderNamePattern NVARCHAR(100) = ?;
DECLARE @projectNamePattern NVARCHAR(100) = ?;

SELECT
Expand All @@ -7,6 +8,8 @@ SELECT
FROM
[catalog].executions e
WHERE
e.folder_name LIKE @folderNamePattern
AND
e.project_name LIKE @projectNamePattern
AND
e.start_time >= DATEADD(HOUR, -@hourspan, SYSDATETIME())
Expand Down
11 changes: 11 additions & 0 deletions query/engine-projects.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
SELECT
f.folder_id,
f.name,
project_id,
p.folder_id,
p.name,
p.[description]
FROM
[catalog].projects p
INNER JOIN
[catalog].folders f ON p.folder_id = f.folder_id
54 changes: 54 additions & 0 deletions query/package-children.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,54 @@
DECLARE @executionIdFilter BIGINT = ?;

WITH
ctePRE AS
(
SELECT * FROM catalog.event_messages em
WHERE em.event_name IN ('OnPreExecute')

),
ctePOST AS
(
SELECT * FROM catalog.event_messages em
WHERE em.event_name IN ('OnPostExecute')
),
cteFINAL AS
(
SELECT
rn = ROW_NUMBER() OVER (PARTITION BY b.event_message_id ORDER BY e.event_message_id),
b.event_message_id,
b.message_source_type,
b.package_path,
b.package_name,
b.execution_path,
b.message_source_name,
pre_message_time = b.message_time,
post_message_time = e.message_time
FROM
ctePRE b
LEFT OUTER JOIN
ctePOST e ON b.operation_id = e.operation_id AND b.package_name = e.package_name AND b.message_source_id = e.message_source_id AND e.event_message_id > b.event_message_id
WHERE
b.operation_id = @executionIdFilter
AND
b.package_path = '\Package'
)
SELECT
event_message_id,
message_source_type,
package_name,
package_path,
execution_path,
message_source_name,
pre_message_time = format(pre_message_time, 'yyyy-MM-dd HH:mm:ss'),
post_message_time = format(post_message_time, 'yyyy-MM-dd HH:mm:ss'),
elapsed_time_min = datediff(mi, pre_message_time, post_message_time)
FROM
cteFINAL
WHERE
rn = 1
AND
CHARINDEX('\', execution_path, 2) > 0
ORDER BY
event_message_id desc
;
63 changes: 43 additions & 20 deletions query/package-history.sql
Original file line number Diff line number Diff line change
@@ -1,22 +1,45 @@
DECLARE @packageNamePattern NVARCHAR(100) = ?;
DECLARE @folderNamePattern NVARCHAR(100) = ?;
DECLARE @projectNamePattern NVARCHAR(100) = ?;
DECLARE @packageNamePattern NVARCHAR(100) = ?;

SELECT TOP (15)
e.execution_id,
e.project_name,
e.package_name,
e.project_lsn,
e.status,
e.start_time,
e.end_time,
elapsed_time_min = datediff(ss, e.start_time, e.end_time) / 60.
FROM
catalog.executions e
WHERE
e.status IN (2,7)
AND
e.package_name like @packageNamePattern
AND
e.project_name LIKE @projectNamePattern
ORDER BY
e.execution_id DESC
WITH cte AS
(
SELECT TOP (15)
e.execution_id,
e.project_name,
e.package_name,
e.project_lsn,
e.status,
e.start_time,
e.end_time,
elapsed_time_min = datediff(ss, e.start_time, e.end_time) / 60.,
avg_elapsed_time_min = avg(datediff(ss, e.start_time, e.end_time) / 60.) OVER (ORDER BY e.start_time ROWS BETWEEN 5 PRECEDING AND CURRENT ROW)
FROM
catalog.executions e
WHERE
e.status IN (2,7)
AND
e.folder_name LIKE @folderNamePattern
AND
e.package_name like @packageNamePattern
AND
e.project_name LIKE @projectNamePattern
ORDER BY
e.execution_id DESC
)
SELECT
execution_id,
project_name,
package_name,
project_lsn,
[status],
start_time = format(start_time, 'yyyy-MM-dd HH:mm:ss'),
end_time = format(CASE WHEN end_time IS NULL THEN dateadd(minute, cast(CEILING(avg_elapsed_time_min) AS int), start_time) ELSE end_time end, 'yyyy-MM-dd HH:mm:ss'),
elapsed_time_min = format(CASE WHEN end_time IS NULL THEN avg_elapsed_time_min ELSE elapsed_time_min end, '#,0.00'),
avg_elapsed_time_min = format(avg_elapsed_time_min, '#,0.00'),
percent_complete = format(100 * (DATEDIFF(ss, start_time, SYSDATETIMEOFFSET()) / 60.) / avg_elapsed_time_min, '#,0.00'),
has_expected_values = CASE WHEN end_time IS NULL THEN 1 ELSE 0 END
FROM
cte
ORDER BY
execution_id DESC
2 changes: 2 additions & 0 deletions query/package-kpi.sql
Original file line number Diff line number Diff line change
@@ -1,10 +1,12 @@
DECLARE @hourspan INT = ?;
DECLARE @folderNamePattern NVARCHAR(100) = ?;
DECLARE @projectNamePattern NVARCHAR(100) = ?;
DECLARE @executionId BIGINT = ?;

WITH cteEID as
(
SELECT execution_id FROM [catalog].executions e WHERE
e.folder_name LIKE @folderNamePattern AND
e.project_name LIKE @projectNamePattern AND
(@executionId = -1 AND e.start_time >= DATEADD(HOUR, -@hourspan, SYSDATETIME())) OR (e.execution_id = @executionId)
),
Expand Down
16 changes: 4 additions & 12 deletions query/package-list.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,5 @@
DECLARE @hourspan INT = ?;
DECLARE @folderNamePattern NVARCHAR(100) = ?;
DECLARE @projectNamePattern NVARCHAR(100) = ?;
DECLARE @statusFilter INT = ?;

Expand Down Expand Up @@ -32,27 +33,18 @@ SELECT TOP 15
e.package_name,
e.project_lsn,
e.status,
status_desc = CASE e.status
WHEN 1 THEN 'Created'
WHEN 2 THEN 'Running'
WHEN 3 THEN 'Cancelled'
WHEN 4 THEN 'Failed'
WHEN 5 THEN 'Pending'
WHEN 6 THEN 'Ended Unexpectedly'
WHEN 7 THEN 'Succeeded'
WHEN 8 THEN 'Stopping'
WHEN 9 THEN 'Completed'
END,
start_time = format(e.start_time, 'yyyy-MM-dd HH:mm:ss'),
end_time = format(e.end_time, 'yyyy-MM-dd HH:mm:ss'),
elapsed_time_min = datediff(ss, e.start_time, e.end_time) / 60.,
elapsed_time_min = format(datediff(ss, e.start_time, e.end_time) / 60., '#,0.00'),
k.warnings,
k.errors
FROM
[catalog].executions e
LEFT OUTER JOIN
cteKPI k ON e.execution_id = k.operation_id
WHERE
e.folder_name LIKE @folderNamePattern
AND
e.project_name LIKE @projectNamePattern
AND
e.start_time >= DATEADD(HOUR, -@hourspan, SYSDATETIME())
Expand Down
2 changes: 1 addition & 1 deletion requirements.txt
Original file line number Diff line number Diff line change
@@ -1 +1 @@
Flask<1
flask
Loading

0 comments on commit 769fe65

Please sign in to comment.