4 |
videos 
5 |
6 |
7 |
21 |
22 |
28 |
29 |
30 |
31 |
32 |
33 | action |
34 | id |
35 | title |
36 | width |
37 | height |
38 | duration (secs) |
39 | FPS |
40 | labels |
41 | download |
42 |
43 |
44 |
45 |
46 |
47 |
48 |
49 |
50 | |
51 | {{ video.Id }} |
52 |
53 | {{ video.Name }}
54 | {{ video.Name }}
55 | |
56 | {{ video.Width }} |
57 | {{ video.Height }} |
58 | {{ video.DurationSeconds.toFixed(2)}} |
59 | {{ video.FramesPerSecond.toFixed(2) }} |
60 |
61 |
62 | {{ label }}
63 |
64 | |
65 | |
66 |
67 |
68 |
69 |
70 |
71 |
72 |
73 |
74 |
75 |
76 |
--------------------------------------------------------------------------------
/public/partials/welcome.html:
--------------------------------------------------------------------------------
1 |
2 |
3 |
4 |
5 |
6 |
welcome, {{user.Name}}
7 | check out your
jobs
8 |
9 |
10 |
11 |
12 |
13 |
--------------------------------------------------------------------------------
/routes/api.js:
--------------------------------------------------------------------------------
1 | var express = require('express');
2 | var router = express.Router();
3 | var multiparty = require('multiparty');
4 | var path = require('path');
5 | var db = require('../storage/db');
6 | var blob = require('../storage/blob');
7 |
8 | module.exports = function () {
9 |
10 | router.post('/jobs', AdminLoggedIn, function (req, res) {
11 | req.body.createdById = req.user.Id;
12 | db.createOrModifyJob(req.body, function (err, result) {
13 | if (err) return logError(err, res);
14 | res.json(result);
15 | });
16 | });
17 |
18 | router.post('/users', AdminLoggedIn, function (req, res) {
19 | db.createOrModifyUser(req.body, function (err, result) {
20 | if (err) return logError(err, res);
21 | res.json(result);
22 | });
23 | });
24 |
25 | router.post('/videos', AdminLoggedIn, function (req, res) {
26 | db.createOrModifyVideo(req.body, function (err, result) {
27 | if (err) return logError(err, res);
28 | res.json(result);
29 | });
30 | });
31 |
32 | router.post('/users', AdminLoggedIn, function (req, res) {
33 | db.createOrModifyUser(req.body, function (err, result) {
34 | if (err) return logError(err, res);
35 | res.json(result);
36 | });
37 | });
38 |
39 | router.get('/videos/:id/url', AdminLoggedIn, function (req, res) {
40 | var id = req.params.id;
41 | console.log('getting url for blob', id);
42 | var url = blob.getVideoUrlWithSasWrite(id);
43 | return res.json({ url: url });
44 | });
45 |
46 | router.post('/videos/:id', AdminLoggedIn, function (req, res) {
47 | var id = req.params.id;
48 | console.log('video uploaded', id);
49 |
50 | db.updateVideoUploaded({id: id}, function(err) {
51 | if (err) return logError(err, res);
52 | return res.json({ status: "OK" });
53 | });
54 | });
55 |
56 | // TODO: check job belong to editor / Admin mode, if Approved check user is Admin
57 | router.post('/jobs/:id/status', EditorLoggedIn, function (req, res) {
58 | var id = req.body.id = req.params.id;
59 | req.body.userId = req.user.Id;
60 | console.log('updating status for job', id);
61 | db.updateJobStatus(req.body, function (err, resp) {
62 | if (err) return logError(err, res);
63 | res.json(resp);
64 | });
65 | });
66 |
67 | router.get('/jobs/statuses', function (req, res) {
68 | console.log('getting jobs statuses');
69 | db.getJobstatuses(function (err, resp) {
70 | if (err) return logError(err, res);
71 | res.json(resp);
72 | });
73 | });
74 |
75 | router.get('/roles', function (req, res) {
76 | console.log('getting roles');
77 | db.getRoles(function (err, resp) {
78 | if (err) return res.status(500).json({ error: err });
79 | res.json(resp);
80 | });
81 | });
82 |
83 | // TODO: check job belong to editor / Admin mode
84 | router.get('/jobs/:id/frames', EditorLoggedIn, function (req, res) {
85 | var id = req.params.id;
86 | console.log('getting frames for job', id);
87 | db.getVideoFramesByJob(id, function (err, resp) {
88 | if (err) return logError(err, res);
89 | res.json(resp);
90 | });
91 | });
92 |
93 | // TODO: check job belong to editor / Admin mode
94 | router.get('/jobs/:id', EditorLoggedIn, function (req, res) {
95 | var id = req.params.id;
96 | console.log('getting job id', id);
97 | db.getJobDetails(id, function (err, resp) {
98 | if (err) return logError(err, res);
99 | res.json(resp);
100 | });
101 | });
102 |
103 | router.get('/jobs', AdminLoggedIn, function (req, res) {
104 | console.log('getting all jobs');
105 | db.getAllJobs(function (err, resp) {
106 | if (err) return logError(err, res);
107 | res.json(resp);
108 | });
109 | });
110 |
111 | // TODO: check job belong to editor / Admin mode
112 | router.post('/jobs/:id/frames/:index', EditorLoggedIn, function (req, res) {
113 | var options = {
114 | tagsJson: req.body.tags
115 | };
116 | options.jobId = req.params.id;
117 | options.frameIndex = req.params.index;
118 |
119 | console.log('posing frame index', options.frameIndex, 'for job', options.jobId);
120 | db.createOrModifyFrame(options, function (err) {
121 | if (err) return logError(err, res);
122 | res.json({});
123 | });
124 | });
125 |
126 | router.get('/users/:id/jobs', [EditorLoggedIn, AuthorizeUserAction], function (req, res) {
127 | var userId = req.user.Id;
128 | console.log('getting jobs for user id', userId);
129 | db.getUserJobs(userId, function (err, resp) {
130 | if (err) return logError(err, res);
131 | res.json(resp);
132 | });
133 | });
134 |
135 | router.get('/videos', AdminLoggedIn, function (req, res) {
136 | var labels = [];
137 | var filter = req.query.filter;
138 | var unassigned = req.query.unassigned == '1' ? 1 : 0;
139 | if (filter) {
140 | var labels = filter.split(',');
141 | console.log('getting videos labeled ' + labels);
142 | }
143 |
144 | return db.getVideos({
145 | labels: labels,
146 | unassigned: unassigned
147 | },
148 | function (err, resp) {
149 | if (err) return res.status(500).json({ error: err });
150 | console.log('resp:', resp);
151 | res.json(resp);
152 | });
153 | });
154 |
155 | router.get('/videos/:id', EditorLoggedIn, function (req, res) {
156 | var id = req.params.id;
157 | console.log('getting video', id);
158 | db.getVideo(id, function (err, resp) {
159 | if (err) return logError(err, res);
160 | res.json(resp);
161 | });
162 | });
163 |
164 | // Not in use- can be used to stream the movie through the API if we
165 | // want to force authentication & authorization
166 | router.get('/videos/:id/movie', EditorLoggedIn, function (req, res) {
167 | var id = req.params.id;
168 | console.log('getting video file', id);
169 |
170 | return blob.getVideoStream({ name: id }, function (err, result) {
171 | if (err) return logError(err, res);
172 |
173 | console.log('stream', result);
174 |
175 | res.setHeader('content-type', result.contentType);
176 | res.setHeader('content-length', result.contentLength);
177 | res.setHeader('etag', result.etag);
178 |
179 | result.stream.on('error', function (err) {
180 | console.error(err);
181 | return res.status(500).json({ message: err.message });
182 | });
183 |
184 | result.stream.pipe(res);
185 | });
186 | });
187 |
188 | router.get('/users/:id', AdminLoggedIn, function (req, res) {
189 | var id = req.params.id;
190 | console.log('getting user', id);
191 | db.getUserById(id, function (err, resp) {
192 | if (err) return logError(err, res);
193 | res.json(resp);
194 | });
195 | });
196 |
197 | router.get('/users', AdminLoggedIn, function (req, res) {
198 | console.log('getting users');
199 | db.getUsers(function (err, resp) {
200 | if (err) return logError(err, res);
201 | res.json(resp);
202 | });
203 | });
204 |
205 | router.get('/videos/:id/frames', EditorLoggedIn, function (req, res) {
206 | var id = req.params.id;
207 | console.log('getting frames for video', id);
208 | db.getVideo(id, function (err, video) {
209 | if (err) return logError(err, res);
210 | db.getVideoFrames(id, function (err, resp) {
211 | if (err) return logError(err, res);
212 | res.setHeader("Content-Type", "application/json");
213 | res.setHeader("Content-Disposition", "attachment;filename=" + video.Name + ".tags.json");
214 | res.setHeader("Content-Transfer-Encoding", "utf-8");
215 | res.json(resp);
216 | });
217 | });
218 | });
219 |
220 | router.get('/labels', AdminLoggedIn, function (req, res) {
221 | console.log('getting all labels');
222 | db.getLabels(function (err, resp) {
223 | if (err) return res.status(500).json({ error: err });
224 | res.json(resp);
225 | });
226 | });
227 |
228 | return router;
229 | }
230 |
231 | function logError(err, res) {
232 | console.error('error:', err);
233 | return res.status(500).json({ message: err.message });
234 | }
235 |
236 | var AdminLoggedIn = getLoggedInForRole(['Admin']);
237 | var EditorLoggedIn = getLoggedInForRole(['Admin', 'Editor']);
238 |
239 | function AuthorizeUserAction(req, res, next) {
240 | var id = req.params.id;
241 | if (id && req.user.RoleName === 'Editor' && req.user.Id != id) {
242 | return res.status(401).json({ error: 'user is not an Admin, can\'t access other user data' });
243 | }
244 | return next();
245 | }
246 |
247 | function getLoggedInForRole(roles) {
248 | return function(req, res, next) {
249 |
250 | // if user is authenticated in the session, and in role
251 | if (!req.isAuthenticated())
252 | return res.status(401).json({ error: 'user not logged in' });
253 |
254 | var found = false;
255 | for (var i = 0; i < roles.length; i++)
256 | if (req.user.RoleName === roles[i]) {
257 | found = true;
258 | break;
259 | }
260 |
261 | if (!found)
262 | return res.status(401).json({ error: 'user not in ' + JSON.stringify(roles) + ' role' });
263 |
264 | return next();
265 | }
266 | }
267 |
--------------------------------------------------------------------------------
/routes/login.js:
--------------------------------------------------------------------------------
1 | var express = require('express');
2 | var router = express.Router();
3 |
4 | module.exports = function (passport) {
5 |
6 | router.get('/login', passport.authenticate('google', { scope : ['https://www.googleapis.com/auth/plus.profile.emails.read'] }));
7 |
8 | // the callback after google has authenticated the user
9 | router.get('/.auth/login/google/callback',
10 | passport.authenticate('google', {
11 | successRedirect : '/#/jobs',
12 | failureRedirect : '/Login'
13 | }));
14 |
15 | router.get('/logout', function (req, res) {
16 | req.logout();
17 | res.redirect('/');
18 | });
19 |
20 | router.get('/profile', isLoggedIn, function (req, res) {
21 | res.json(req.user);
22 | });
23 |
24 | return router;
25 | };
26 |
27 | // route middleware to make sure a user is logged in
28 | function isLoggedIn(req, res, next) {
29 |
30 | // if user is authenticated in the session, carry on
31 | if (req.isAuthenticated())
32 | return next();
33 |
34 | // if they aren't redirect them to the home page
35 | //res.redirect('/');
36 | return res.status(401).json({ error: 'user not logged in' });
37 | }
--------------------------------------------------------------------------------
/server.js:
--------------------------------------------------------------------------------
1 |
2 | var express = require('express');
3 | var path = require('path');
4 | var bodyParser = require('body-parser');
5 | var api = require('./routes/api');
6 |
7 | var passport = require('passport');
8 | var flash = require('connect-flash');
9 | var morgan = require('morgan');
10 | var cookieParser = require('cookie-parser');
11 | var bodyParser = require('body-parser');
12 | var session = require('express-session');
13 |
14 | require('./auth/passport')(passport);
15 |
16 | var app = express();
17 |
18 | app.use(morgan('dev')); // log every request to the console
19 |
20 | app.use(cookieParser()); // read cookies (needed for auth)
21 | app.use(bodyParser.json());
22 | app.use(bodyParser.urlencoded({ extended: false }));
23 |
24 |
25 | // required for passport
26 | app.use(session({ secret: 'mysecretsesson123456789' })); // session secret
27 | app.use(passport.initialize());
28 | app.use(passport.session()); // persistent login sessions
29 | app.use(flash()); // use connect-flash for flash messages stored in session
30 |
31 | app.use(require('./routes/login')(passport));
32 | app.use('/api', api());
33 |
34 | app.use(express.static(path.join(__dirname, 'public')));
35 |
36 | app.use(function (req, res) {
37 | return res.status(404).json({ error: 'not found' });
38 | });
39 |
40 | app.set('port', process.env.PORT || 3000);
41 |
42 | var server = app.listen(app.get('port'), function() {
43 | console.log('Express server listening on port ' + server.address().port);
44 | });
45 |
46 |
--------------------------------------------------------------------------------
/storage/blob.js:
--------------------------------------------------------------------------------
1 | var azure = require('azure-storage');
2 | var config = require('../config');
3 | var url = require('url');
4 |
5 | var CONTAINER_NAME = 'vidoes';
6 | var URL_FORMAT = 'https://
.blob.core.windows.net/'
7 | .replace('', config.storage.account)
8 | .replace('', CONTAINER_NAME);
9 |
10 | var blobSvc = azure.createBlobService(config.storage.account, config.storage.key);
11 |
12 | var cbUrl = config.auth.google.callbackURL,
13 | cbUrlElements = url.parse(cbUrl),
14 | host = cbUrlElements.protocol + '//' + cbUrlElements.host;
15 |
16 | console.log('enabling blob CORS for host', host);
17 | var serviceProperties = {
18 | Cors: {
19 | CorsRule: [{
20 | AllowedOrigins: [host],
21 | AllowedMethods: ['GET', 'PUT'],
22 | AllowedHeaders: ['*'],
23 | ExposedHeaders: ['*'],
24 | MaxAgeInSeconds: 30 * 60
25 | }]
26 | }
27 | };
28 |
29 | blobSvc.setServiceProperties(serviceProperties, function (err, result) {
30 | if (err) return console.error('error setting service properties', err);
31 | console.log('result:', result);
32 |
33 | blobSvc.createContainerIfNotExists(CONTAINER_NAME, { publicAccessLevel : 'blob' },
34 | function (err, result, response) {
35 | if (err) return console.error('error creating container', CONTAINER_NAME, err);
36 | });
37 | });
38 |
39 | function upload(opts, cb) {
40 | return blobSvc.createBlockBlobFromStream(CONTAINER_NAME, opts.name, opts.stream, opts.size,
41 | { contentType: opts.contentType },
42 | function (err, file, result) {
43 | if (err) {
44 | console.error('error saving blob', opts, err);
45 | return cb(err);
46 | }
47 | return cb(null, { url: URL_FORMAT + '/' + opts.name });
48 | });
49 | }
50 |
51 | function getSAS(opts) {
52 |
53 | var permissions = opts.permissions || azure.BlobUtilities.SharedAccessPermissions.READ;
54 | var startDate = new Date();
55 | var expiryDate = new Date(startDate);
56 | expiryDate.setMinutes(startDate.getMinutes() + 30);
57 | startDate.setMinutes(startDate.getMinutes() - 10);
58 |
59 | var sharedAccessPolicy = {
60 | AccessPolicy: {
61 | Permissions: permissions,
62 | Start: startDate,
63 | Expiry: expiryDate
64 | }
65 | };
66 | var sasToken = blobSvc.generateSharedAccessSignature(CONTAINER_NAME, opts.name + '', sharedAccessPolicy);
67 | console.log('sasToken', sasToken);
68 | return sasToken;
69 | }
70 |
71 | function getVideoStream(opts, cb) {
72 | return blobSvc.getBlobProperties(CONTAINER_NAME, opts.name, function(err, props){
73 | if (err) return cb(err);
74 | var stream = blobSvc.createReadStream(CONTAINER_NAME, opts.name);
75 | return cb(null, {
76 | stream: stream,
77 | contentType: props.contentType,
78 | contentLength: props.contentLength,
79 | etag: props.etag
80 | });
81 |
82 | });
83 | }
84 |
85 | function getVideoUrl(id) {
86 | return URL_FORMAT + '/' + id;
87 | }
88 |
89 | function getVideoUrlWithSas(id) {
90 | return getVideoUrl(id) + '?' + getSAS({ name: id });
91 | }
92 |
93 | function getVideoUrlWithSasWrite(id) {
94 | return getVideoUrl(id) + '?' + getSAS({ name: id,
95 | permissions: azure.BlobUtilities.SharedAccessPermissions.WRITE});
96 | }
97 |
98 | module.exports = {
99 | upload: upload,
100 | getVideoStream: getVideoStream,
101 | getVideoUrlWithSas: getVideoUrlWithSas,
102 | getVideoUrlWithSasWrite: getVideoUrlWithSasWrite
103 | };
104 |
105 |
106 |
--------------------------------------------------------------------------------
/storage/db.js:
--------------------------------------------------------------------------------
1 | var tedious = require('tedious');
2 | var TYPES = tedious.TYPES;
3 | var configSql = require('../config').sql;
4 |
5 | var DBErrors = {
6 | duplicate: 2601
7 | }
8 |
9 | var blob = require('./blob');
10 |
11 | function connect(cb) {
12 | console.log('connecting to server', configSql.server);
13 |
14 | var Connection = tedious.Connection;
15 | var connection = new Connection(configSql);
16 |
17 | connection.on('connect', function(err) {
18 | if (err) {
19 | console.error('error connecting to sql server', configSql.server);
20 | return cb(err);
21 | }
22 | console.log('connection established', !connection.closed);
23 | return cb(null, connection);
24 | });
25 | }
26 |
27 | function normalizeVideoRow(video) {
28 | if(video.VideoJson)
29 | video.Data = JSON.parse(video.VideoJson);
30 | delete video.VideoJson;
31 |
32 | video.Url = blob.getVideoUrlWithSas(video.Id);
33 | return video;
34 | }
35 |
36 | function normalizeFrameRow(frame) {
37 | if(frame.TagsJson)
38 | frame.Tags = JSON.parse(frame.TagsJson);
39 | delete frame.TagsJson;
40 | return frame;
41 | }
42 |
43 | function normalizeJobRow(job) {
44 | if(job.ConfigJson)
45 | job.Config = JSON.parse(job.ConfigJson);
46 | delete job.ConfigJson;
47 | return job;
48 | }
49 |
50 | function getJobDetails(id, cb) {
51 | return getDataSets({
52 | sproc: 'GetJob',
53 | sets: ['job', 'video', 'user', 'frames'],
54 | params: [{name: 'Id', type: TYPES.Int, value: id}]
55 | }, function(err, result){
56 | if (err) return logError(err, cb);
57 |
58 | var newResult = {
59 | job: result.job[0],
60 | video: result.video[0],
61 | user: result.user[0]
62 | };
63 |
64 | try {
65 | normalizeJobRow(newResult.job);
66 | normalizeVideoRow(newResult.video);
67 | }
68 | catch (err) {
69 | return logError(err, cb);
70 | }
71 |
72 | return cb(null, newResult);
73 | });
74 | }
75 |
76 | function getUsers(cb) {
77 | return getDataSets({
78 | sproc: 'GetUsers',
79 | sets: ['users'],
80 | params: []
81 | }, function (err, result) {
82 | if (err) return logError(err, cb);
83 |
84 | var newResult = {
85 | users: []
86 | };
87 |
88 | try {
89 | for (var i = 0; i < result.users.length; i++) {
90 | newResult.users.push(result.users[i]);
91 | }
92 | }
93 | catch (err) {
94 | return logError(err, cb);
95 | }
96 |
97 | return cb(null, newResult);
98 | });
99 | }
100 |
101 | function createOrModifyUser(req, cb) {
102 | connect(function (err, connection) {
103 | if (err) return cb(err);
104 |
105 | try {
106 | var resultUserId;
107 |
108 | var request = new tedious.Request('UpsertUser', function (err) {
109 | if (err) return logError(err, cb);
110 | return cb(null, { userId: resultUserId });
111 | });
112 |
113 | if (req.id)
114 | request.addParameter('Id', TYPES.Int, req.id);
115 |
116 | request.addParameter('Name', TYPES.NVarChar, req.name);
117 | request.addParameter('Email', TYPES.NVarChar, req.email);
118 | request.addParameter('RoleId', TYPES.TinyInt, req.roleId);
119 |
120 | request.addOutputParameter('UserId', TYPES.Int);
121 |
122 | request.on('returnValue', function (parameterName, value, metadata) {
123 | if (parameterName == 'UserId') {
124 | resultUserId = value;
125 | }
126 | });
127 |
128 | connection.callProcedure(request);
129 | }
130 | catch (err) {
131 | return cb(err);
132 | }
133 |
134 | });
135 | }
136 |
137 | function updateJobStatus(req, cb) {
138 | connect(function (err, connection) {
139 | if (err) return cb(err);
140 |
141 | try {
142 |
143 | var request = new tedious.Request('UpdateJobStatus', function (err) {
144 | if (err) return logError(err, cb);
145 | return cb();
146 | });
147 |
148 | request.addParameter('Id', TYPES.Int, req.id);
149 | request.addParameter('UserId', TYPES.Int, req.userId);
150 | request.addParameter('StatusId', TYPES.TinyInt, req.statusId);
151 |
152 | connection.callProcedure(request);
153 | }
154 | catch (err) {
155 | return cb(err);
156 | }
157 |
158 | });
159 | }
160 |
161 | function updateVideoUploaded(req, cb) {
162 | connect(function (err, connection) {
163 | if (err) return cb(err);
164 |
165 | try {
166 |
167 | var request = new tedious.Request('UpdateVideoUploaded', function (err) {
168 | if (err) return logError(err, cb);
169 | return cb();
170 | });
171 |
172 | request.addParameter('Id', TYPES.Int, req.id);
173 | connection.callProcedure(request);
174 | }
175 | catch (err) {
176 | return cb(err);
177 | }
178 |
179 | });
180 | }
181 |
182 | function getJobstatuses(cb) {
183 | return getDataSets({
184 | sproc: 'GetJobStatuses',
185 | sets: ['statuses'],
186 | params: []
187 | }, function (err, result) {
188 | if (err) return logError(err, cb);
189 | return cb(null, result);
190 | });
191 | }
192 |
193 | function getRoles(cb) {
194 | return getDataSets({
195 | sproc: 'GetRoles',
196 | sets: ['roles'],
197 | params: []
198 | }, function (err, result) {
199 | if (err) return logError(err, cb);
200 | return cb(null, result);
201 | });
202 | }
203 |
204 | function getVideo(id, cb) {
205 | return getDataSets({
206 | sproc: 'GetVideo',
207 | sets: ['videos'],
208 | params: [{ name: 'Id', type: TYPES.Int, value: id }]
209 | }, function (err, result) {
210 | if (err) return logError(err, cb);
211 |
212 | if (result.videos.length) {
213 | return cb(null, normalizeVideoRow(result.videos[0]));
214 | }
215 |
216 | return cb(null, {});
217 | });
218 | }
219 |
220 | function getUserById(id, cb) {
221 | return getDataSets({
222 | sproc: 'GetUserById',
223 | sets: ['users'],
224 | params: [{ name: 'Id', type: TYPES.Int, value: id}]
225 | }, function (err, result) {
226 | if (err) return logError(err, cb);
227 |
228 | if (result.users.length) {
229 | return cb(null, result.users[0]);
230 | }
231 |
232 | return cb(null, {});
233 | });
234 | }
235 |
236 | function getUserByEmail(email, cb) {
237 | return getDataSets({
238 | sproc: 'GetUserByEmail',
239 | sets: ['users'],
240 | params: [{ name: 'Email', type: TYPES.VarChar, value: email }]
241 | }, function (err, result) {
242 | if (err) return logError(err, cb);
243 |
244 | if (result.users && result.users.length) {
245 | return cb(null, result.users[0]);
246 | }
247 |
248 | return cb();
249 | });
250 | }
251 |
252 | function createOrModifyVideo(req, cb) {
253 | connect(function (err, connection) {
254 | if (err) return cb(err);
255 |
256 | try {
257 | var resultVideoId;
258 |
259 | var request = new tedious.Request('UpsertVideo', function (err) {
260 | if (err) return logError(err, cb);
261 | return cb(null, { videoId: resultVideoId });
262 | });
263 |
264 | if (req.id)
265 | request.addParameter('Id', TYPES.Int, req.id);
266 |
267 | request.addParameter('Name', TYPES.NVarChar, req.name);
268 | request.addParameter('Width', TYPES.Int, req.width);
269 | request.addParameter('Height', TYPES.Int, req.height);
270 | request.addParameter('DurationSeconds', TYPES.Real, req.durationSeconds);
271 | request.addParameter('FramesPerSecond', TYPES.Real, req.framesPerSecond);
272 |
273 | var table = {
274 | columns: [ { name: '[Name]', type: TYPES.VarChar } ],
275 | rows: []
276 | };
277 |
278 | for (var i=0; i < req.labels.length; i++) {
279 | table.rows.push([req.labels[i]]);
280 | }
281 | request.addParameter('udtLabels', TYPES.TVP, table);
282 |
283 | if (req.videoJson)
284 | request.addParameter('VideoJson', TYPES.NVarChar, JSON.stringify(req.videoJson));
285 |
286 | request.addOutputParameter('VideoId', TYPES.Int);
287 |
288 | request.on('returnValue', function (parameterName, value, metadata) {
289 | if (parameterName == 'VideoId') {
290 | resultVideoId = value;
291 | }
292 | });
293 |
294 | connection.callProcedure(request);
295 | }
296 | catch (err) {
297 | return logError(err, cb);
298 | }
299 |
300 | });
301 | }
302 |
303 | function createOrModifyJob(req, cb) {
304 | connect(function(err, connection){
305 | if (err) return logError(err, cb);
306 |
307 | try
308 | {
309 | var resultJobId;
310 |
311 | var request = new tedious.Request('UpsertJob', function(err) {
312 | if (err && err.number == DBErrors.duplicate) return logError(new Error('video already assigned to user'), cb);
313 | if (err) return logError(err, cb);
314 |
315 | return cb(null, {jobId: resultJobId});
316 | });
317 |
318 | if(req.id)
319 | request.addParameter('Id', TYPES.Int, req.id);
320 |
321 | request.addParameter('VideoId', TYPES.Int, req.videoId);
322 | request.addParameter('UserId', TYPES.Int, req.userId);
323 | request.addParameter('StatusId', TYPES.TinyInt, req.statusId);
324 | request.addParameter('Description', TYPES.VarChar, req.description);
325 | request.addParameter('CreatedById', TYPES.Int, req.createdById);
326 |
327 | if(req.configJson)
328 | request.addParameter('ConfigJson', TYPES.NVarChar, JSON.stringify(req.configJson));
329 |
330 | request.addOutputParameter('JobId', TYPES.Int);
331 |
332 | request.on('returnValue', function(parameterName, value, metadata) {
333 | if (parameterName == 'JobId') {
334 | resultJobId = value;
335 | }
336 | });
337 |
338 | connection.callProcedure(request);
339 | }
340 | catch(err) {
341 | return logError(err, cb);
342 | }
343 |
344 | });
345 | }
346 |
347 | function getDataSets(opts, cb) {
348 | connect(function(err, connection){
349 | if (err) return logError(err, cb);
350 |
351 | var sproc = opts.sproc,
352 | sets = opts.sets,
353 | params = opts.params,
354 | currSetIndex = -1;
355 |
356 | var result = {};
357 |
358 | var request = new tedious.Request(sproc, function(err, rowCount, rows) {
359 | if (err) return logError(err, cb);
360 | });
361 |
362 | for (var i=0; i createdb.log';
34 | child_process.exec(createdb_command, null, function (error, stdout, stderr) {
35 |
36 | if (error) return console.error('Error creating new DB schema', error);
37 |
38 |
39 | //insert admin user
40 | var insertAdmin = 'sqlcmd -U %DB_USER% -S %DB_SERVER% -P %DB_PASSWORD% -d %DB_NAME% -Q ' + '"INSERT INTO [dbo].[Users] ([Name] ,[Email] ,[RoleId]) VALUES (\'%DB_USER%\' ,\'%DB_EMAIL%\' ,2)"';
41 | child_process.exec(insertAdmin, null, function (error, stdout, stderr) {
42 |
43 | if (error) return console.error('Error inserting admin', error);
44 | return console.info('DB schema deployed successfully');
45 | });
46 |
47 | });
48 | });
49 | }
--------------------------------------------------------------------------------
/storage/sql/schema.sql:
--------------------------------------------------------------------------------
1 | /****** Object: UserDefinedTableType [dbo].[UDT_LabelsList] Script Date: 1/12/2016 1:42:58 AM ******/
2 | CREATE TYPE [dbo].[UDT_LabelsList] AS TABLE(
3 | [Name] [varchar](50) NULL
4 | )
5 | GO
6 | /****** Object: UserDefinedTableType [dbo].[UDT_VideoLabelsList] Script Date: 1/12/2016 1:42:58 AM ******/
7 | CREATE TYPE [dbo].[UDT_VideoLabelsList] AS TABLE(
8 | [LabelId] [int] NULL
9 | )
10 | GO
11 | /****** Object: Table [dbo].[Frames] Script Date: 1/12/2016 1:42:58 AM ******/
12 | SET ANSI_NULLS ON
13 | GO
14 | SET QUOTED_IDENTIFIER ON
15 | GO
16 | CREATE TABLE [dbo].[Frames](
17 | [JobId] [int] NOT NULL,
18 | [FrameIndex] [bigint] NOT NULL,
19 | [TagsJson] [ntext] NULL,
20 | CONSTRAINT [PK_Frames] PRIMARY KEY CLUSTERED
21 | (
22 | [JobId] ASC,
23 | [FrameIndex] ASC
24 | )
25 | ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
26 |
27 | GO
28 | /****** Object: Table [dbo].[Jobs] Script Date: 1/12/2016 1:42:58 AM ******/
29 | SET ANSI_NULLS ON
30 | GO
31 | SET QUOTED_IDENTIFIER ON
32 | GO
33 | CREATE TABLE [dbo].[Jobs](
34 | [Id] [int] IDENTITY(1,1) NOT NULL,
35 | [VideoId] [int] NOT NULL,
36 | [UserId] [int] NOT NULL,
37 | [Description] [nvarchar](1024) NULL,
38 | [CreatedById] [int] NULL,
39 | [ReviewedById] [int] NULL,
40 | [ConfigJson] [ntext] NULL,
41 | [CreateDate] [datetime] NOT NULL,
42 | [StatusId] [tinyint] NOT NULL,
43 | CONSTRAINT [PK_Jobs] PRIMARY KEY CLUSTERED
44 | (
45 | [Id] ASC
46 | )
47 | ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
48 |
49 | GO
50 | /****** Object: Table [dbo].[JobStatus] Script Date: 1/12/2016 1:42:58 AM ******/
51 | SET ANSI_NULLS ON
52 | GO
53 | SET QUOTED_IDENTIFIER ON
54 | GO
55 | CREATE TABLE [dbo].[JobStatus](
56 | [Id] [tinyint] NOT NULL,
57 | [Name] [nvarchar](50) NOT NULL,
58 | [Description] [nvarchar](100) NULL,
59 | CONSTRAINT [PK_JobStatus] PRIMARY KEY CLUSTERED
60 | (
61 | [Id] ASC
62 | )
63 | ) ON [PRIMARY]
64 |
65 | GO
66 | /****** Object: Table [dbo].[Labels] Script Date: 1/12/2016 1:42:58 AM ******/
67 | SET ANSI_NULLS ON
68 | GO
69 | SET QUOTED_IDENTIFIER ON
70 | GO
71 | CREATE TABLE [dbo].[Labels](
72 | [Id] [int] IDENTITY(1,1) NOT NULL,
73 | [Name] [nvarchar](50) NOT NULL,
74 | CONSTRAINT [PK_Labels] PRIMARY KEY CLUSTERED
75 | (
76 | [Id] ASC
77 | ),
78 | CONSTRAINT [IX_Labels_Name] UNIQUE NONCLUSTERED
79 | (
80 | [Name] ASC
81 | )
82 | ) ON [PRIMARY]
83 |
84 | GO
85 | /****** Object: Table [dbo].[Roles] Script Date: 1/12/2016 1:42:58 AM ******/
86 | SET ANSI_NULLS ON
87 | GO
88 | SET QUOTED_IDENTIFIER ON
89 | GO
90 | SET ANSI_PADDING ON
91 | GO
92 | CREATE TABLE [dbo].[Roles](
93 | [Id] [tinyint] NOT NULL,
94 | [Name] [varchar](50) NOT NULL,
95 | [Description] [nchar](1024) NULL,
96 | CONSTRAINT [PK_Roles] PRIMARY KEY CLUSTERED
97 | (
98 | [Id] ASC
99 | )
100 | ) ON [PRIMARY]
101 |
102 | GO
103 | SET ANSI_PADDING OFF
104 | GO
105 | /****** Object: Table [dbo].[Users] Script Date: 1/12/2016 1:42:58 AM ******/
106 | SET ANSI_NULLS ON
107 | GO
108 | SET QUOTED_IDENTIFIER ON
109 | GO
110 | SET ANSI_PADDING ON
111 | GO
112 | CREATE TABLE [dbo].[Users](
113 | [Id] [int] IDENTITY(1,1) NOT NULL,
114 | [Name] [nvarchar](50) NOT NULL,
115 | [Email] [varchar](100) NOT NULL,
116 | [RoleId] [tinyint] NOT NULL,
117 | CONSTRAINT [PK_Users] PRIMARY KEY CLUSTERED
118 | (
119 | [Id] ASC
120 | )
121 | ) ON [PRIMARY]
122 |
123 | GO
124 | SET ANSI_PADDING OFF
125 | GO
126 | /****** Object: Table [dbo].[VideoLabels] Script Date: 1/12/2016 1:42:58 AM ******/
127 | SET ANSI_NULLS ON
128 | GO
129 | SET QUOTED_IDENTIFIER ON
130 | GO
131 | CREATE TABLE [dbo].[VideoLabels](
132 | [VideoId] [int] NOT NULL,
133 | [LabelId] [int] NOT NULL,
134 | CONSTRAINT [PK_VideoLabels] PRIMARY KEY CLUSTERED
135 | (
136 | [VideoId] ASC,
137 | [LabelId] ASC
138 | )
139 | ) ON [PRIMARY]
140 |
141 | GO
142 | /****** Object: Table [dbo].[Videos] Script Date: 1/12/2016 1:42:58 AM ******/
143 | SET ANSI_NULLS ON
144 | GO
145 | SET QUOTED_IDENTIFIER ON
146 | GO
147 | CREATE TABLE [dbo].[Videos](
148 | [Id] [int] IDENTITY(1,1) NOT NULL,
149 | [Name] [nvarchar](100) NOT NULL,
150 | [Width] [int] NOT NULL,
151 | [Height] [int] NOT NULL,
152 | [DurationSeconds] [real] NOT NULL,
153 | [FramesPerSecond] [real] NOT NULL,
154 | [VideoJson] [ntext] NULL,
155 | [VideoUploaded] [bit] NULL,
156 | CONSTRAINT [PK_Videos] PRIMARY KEY CLUSTERED
157 | (
158 | [Id] ASC
159 | )
160 | ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
161 |
162 | GO
163 | /****** Object: Index [IX_Jobs] Script Date: 1/12/2016 1:42:58 AM ******/
164 | CREATE UNIQUE NONCLUSTERED INDEX [IX_Jobs] ON [dbo].[Jobs]
165 | (
166 | [UserId] ASC,
167 | [VideoId] ASC
168 | )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
169 | GO
170 | SET ANSI_PADDING ON
171 |
172 | GO
173 | /****** Object: Index [IX_Users_Email] Script Date: 1/12/2016 1:42:58 AM ******/
174 | CREATE UNIQUE NONCLUSTERED INDEX [IX_Users_Email] ON [dbo].[Users]
175 | (
176 | [Email] ASC
177 | )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
178 | GO
179 | ALTER TABLE [dbo].[Frames] WITH CHECK ADD CONSTRAINT [FK_Frames_Jobs] FOREIGN KEY([JobId])
180 | REFERENCES [dbo].[Jobs] ([Id])
181 | GO
182 | ALTER TABLE [dbo].[Frames] CHECK CONSTRAINT [FK_Frames_Jobs]
183 | GO
184 | ALTER TABLE [dbo].[Jobs] WITH CHECK ADD CONSTRAINT [FK_Jobs_JobStatus] FOREIGN KEY([StatusId])
185 | REFERENCES [dbo].[JobStatus] ([Id])
186 | GO
187 | ALTER TABLE [dbo].[Jobs] CHECK CONSTRAINT [FK_Jobs_JobStatus]
188 | GO
189 | ALTER TABLE [dbo].[Jobs] WITH CHECK ADD CONSTRAINT [FK_Jobs_Users] FOREIGN KEY([UserId])
190 | REFERENCES [dbo].[Users] ([Id])
191 | GO
192 | ALTER TABLE [dbo].[Jobs] CHECK CONSTRAINT [FK_Jobs_Users]
193 | GO
194 | ALTER TABLE [dbo].[Jobs] WITH CHECK ADD CONSTRAINT [FK_Jobs_Users_CreatedById] FOREIGN KEY([CreatedById])
195 | REFERENCES [dbo].[Users] ([Id])
196 | GO
197 | ALTER TABLE [dbo].[Jobs] CHECK CONSTRAINT [FK_Jobs_Users_CreatedById]
198 | GO
199 | ALTER TABLE [dbo].[Jobs] WITH CHECK ADD CONSTRAINT [FK_Jobs_Users_ReviewedByAdmin] FOREIGN KEY([ReviewedById])
200 | REFERENCES [dbo].[Users] ([Id])
201 | GO
202 | ALTER TABLE [dbo].[Jobs] CHECK CONSTRAINT [FK_Jobs_Users_ReviewedByAdmin]
203 | GO
204 | ALTER TABLE [dbo].[Jobs] WITH CHECK ADD CONSTRAINT [FK_Jobs_Videos] FOREIGN KEY([VideoId])
205 | REFERENCES [dbo].[Videos] ([Id])
206 | GO
207 | ALTER TABLE [dbo].[Jobs] CHECK CONSTRAINT [FK_Jobs_Videos]
208 | GO
209 | ALTER TABLE [dbo].[Users] WITH CHECK ADD CONSTRAINT [FK_Users_Roles] FOREIGN KEY([RoleId])
210 | REFERENCES [dbo].[Roles] ([Id])
211 | GO
212 | ALTER TABLE [dbo].[Users] CHECK CONSTRAINT [FK_Users_Roles]
213 | GO
214 | ALTER TABLE [dbo].[VideoLabels] WITH CHECK ADD CONSTRAINT [FK_VideoLabels_Labels] FOREIGN KEY([LabelId])
215 | REFERENCES [dbo].[Labels] ([Id])
216 | GO
217 | ALTER TABLE [dbo].[VideoLabels] CHECK CONSTRAINT [FK_VideoLabels_Labels]
218 | GO
219 | ALTER TABLE [dbo].[VideoLabels] WITH CHECK ADD CONSTRAINT [FK_VideoLabels_Videos] FOREIGN KEY([VideoId])
220 | REFERENCES [dbo].[Videos] ([Id])
221 | GO
222 | ALTER TABLE [dbo].[VideoLabels] CHECK CONSTRAINT [FK_VideoLabels_Videos]
223 | GO
224 | /****** Object: StoredProcedure [dbo].[GetAllJobs] Script Date: 1/12/2016 1:42:58 AM ******/
225 | SET ANSI_NULLS ON
226 | GO
227 | SET QUOTED_IDENTIFIER ON
228 | GO
229 |
230 | CREATE PROCEDURE [dbo].[GetAllJobs]
231 | AS
232 | BEGIN
233 | SELECT j.Id as JobId, j.Description, j.CreatedById, u1.Name as CreatedByName, j.UserId, u3.Name as UserName, j.ReviewedById, u2.Name as ReviewedByName, j.CreateDate, 'TODO' as Progress,
234 | j.ConfigJson, j.StatusId, js.Name as StatusName, v.Id as VideoId, v.Name as VideoName, v.Width, v.Height, v.DurationSeconds, v.FramesPerSecond, v.VideoJson
235 | FROM Jobs j
236 | JOIN Videos v
237 | ON j.VideoId = v.Id
238 | LEFT JOIN USERS u1 ON j.CreatedById = u1.Id
239 | LEFT JOIN USERS u2 ON j.ReviewedById = u2.Id
240 | LEFT JOIN USERS u3 ON j.UserId = u3.Id
241 | JOIN JobStatus js ON js.Id = j.StatusId
242 | END
243 |
244 |
245 |
246 |
247 |
248 | GO
249 | /****** Object: StoredProcedure [dbo].[GetJob] Script Date: 1/12/2016 1:42:58 AM ******/
250 | SET ANSI_NULLS ON
251 | GO
252 | SET QUOTED_IDENTIFIER ON
253 | GO
254 | CREATE PROCEDURE [dbo].[GetJob]
255 | @Id int
256 | AS
257 | BEGIN
258 |
259 | DECLARE @UserId int = -1
260 | DECLARE @VideoId int = 0
261 |
262 | SELECT @UserId = j.UserId, @VideoId = j.VideoId
263 | FROM Jobs j
264 | WHERE j.Id = @Id
265 |
266 | SELECT * FROM Jobs WHERE Id = @Id
267 |
268 | SELECT * FROM Videos WHERE Id = @VideoId
269 |
270 | SELECT * FROM Users WHERE Id = @UserId
271 |
272 | SELECT * FROM Frames WHERE JobId = @Id
273 |
274 | RETURN 1
275 |
276 | END
277 |
278 |
279 |
280 |
281 |
282 | GO
283 | /****** Object: StoredProcedure [dbo].[GetJobStatuses] Script Date: 1/12/2016 1:42:58 AM ******/
284 | SET ANSI_NULLS ON
285 | GO
286 | SET QUOTED_IDENTIFIER ON
287 | GO
288 | CREATE PROCEDURE [dbo].[GetJobStatuses]
289 | AS
290 | BEGIN
291 |
292 | SELECT *
293 | FROM JobStatus
294 |
295 | END
296 |
297 |
298 |
299 | GO
300 | /****** Object: StoredProcedure [dbo].[GetLabels] Script Date: 1/12/2016 1:42:58 AM ******/
301 | SET ANSI_NULLS ON
302 | GO
303 | SET QUOTED_IDENTIFIER ON
304 | GO
305 | CREATE PROCEDURE [dbo].[GetLabels]
306 | AS
307 | BEGIN
308 | SELECT * FROM [dbo].[Labels] ORDER BY [Labels].[Name] ASC
309 | END
310 |
311 | GO
312 | /****** Object: StoredProcedure [dbo].[GetRoles] Script Date: 1/12/2016 1:42:58 AM ******/
313 | SET ANSI_NULLS ON
314 | GO
315 | SET QUOTED_IDENTIFIER ON
316 | GO
317 | CREATE PROCEDURE [dbo].[GetRoles]
318 | AS
319 | BEGIN
320 |
321 | SELECT *
322 | FROM Roles
323 |
324 | END
325 |
326 |
327 |
328 | GO
329 | /****** Object: StoredProcedure [dbo].[GetUserByEmail] Script Date: 1/12/2016 1:42:58 AM ******/
330 | SET ANSI_NULLS ON
331 | GO
332 | SET QUOTED_IDENTIFIER ON
333 | GO
334 | CREATE PROCEDURE [dbo].[GetUserByEmail]
335 | @Email varchar(100)
336 | AS
337 | BEGIN
338 |
339 | SELECT u.*, r.Name as RoleName
340 | FROM Users u
341 | JOIN Roles r
342 | ON u.RoleId = r.Id
343 | WHERE u.Email = @Email
344 |
345 | RETURN 1
346 |
347 | END
348 |
349 |
350 |
351 |
352 |
353 | GO
354 | /****** Object: StoredProcedure [dbo].[GetUserById] Script Date: 1/12/2016 1:42:58 AM ******/
355 | SET ANSI_NULLS ON
356 | GO
357 | SET QUOTED_IDENTIFIER ON
358 | GO
359 | CREATE PROCEDURE [dbo].[GetUserById]
360 | @Id int
361 | AS
362 | BEGIN
363 |
364 | SELECT u.*, r.Name as RoleName
365 | FROM Users u
366 | JOIN Roles r
367 | ON u.RoleId = r.Id
368 | WHERE u.Id = @Id
369 |
370 | RETURN 1
371 |
372 | END
373 |
374 |
375 |
376 |
377 |
378 | GO
379 | /****** Object: StoredProcedure [dbo].[GetUserJobs] Script Date: 1/12/2016 1:42:58 AM ******/
380 | SET ANSI_NULLS ON
381 | GO
382 | SET QUOTED_IDENTIFIER ON
383 | GO
384 | CREATE PROCEDURE [dbo].[GetUserJobs]
385 | @UserId int
386 | AS
387 | BEGIN
388 | SELECT j.Id as JobId, j.Description, j.CreatedById, u1.Name as CreatedByName, j.UserId, u3.Name as UserName, j.ReviewedById, u2.Name as ReviewedByName, j.CreateDate, 40 as Progress,
389 | j.ConfigJson, j.StatusId, js.Name as StatusName, v.Id as VideoId, v.Name as VideoName, v.Width, v.Height, v.DurationSeconds, v.FramesPerSecond, v.VideoJson
390 | FROM Jobs j
391 | JOIN Videos v
392 | ON j.UserId = @UserId AND j.VideoId = v.Id
393 | LEFT JOIN USERS u1 ON j.CreatedById = u1.Id
394 | LEFT JOIN USERS u2 ON j.ReviewedById = u2.Id
395 | LEFT JOIN USERS u3 ON j.UserId = u3.Id
396 | JOIN JobStatus js ON js.Id = j.StatusId
397 | END
398 |
399 |
400 |
401 |
402 | GO
403 | /****** Object: StoredProcedure [dbo].[GetUsers] Script Date: 1/12/2016 1:42:58 AM ******/
404 | SET ANSI_NULLS ON
405 | GO
406 | SET QUOTED_IDENTIFIER ON
407 | GO
408 | CREATE PROCEDURE [dbo].[GetUsers]
409 | AS
410 |
411 | BEGIN
412 |
413 | SELECT u.*, r.Name as RoleName
414 | FROM Users u
415 | JOIN Roles r
416 | ON u.RoleId = r.Id
417 |
418 | END
419 |
420 |
421 |
422 |
423 | GO
424 | /****** Object: StoredProcedure [dbo].[GetVideo] Script Date: 1/12/2016 1:42:58 AM ******/
425 | SET ANSI_NULLS ON
426 | GO
427 | SET QUOTED_IDENTIFIER ON
428 | GO
429 |
430 |
431 | CREATE PROCEDURE [dbo].[GetVideo]
432 | @Id int
433 | AS
434 | BEGIN
435 | SELECT v.*,
436 | stuff(
437 | ( SELECT ','+ l.Name
438 | FROM VideoLabels vl
439 | JOIN Labels l
440 | ON vl.LabelId = l.Id
441 | AND vl.VideoId = v.Id
442 | FOR XML PATH('')
443 | ),1,1,'') AS Labels
444 | FROM (SELECT * FROM Videos) v
445 | WHERE Id = @Id
446 | END
447 |
448 |
449 |
450 |
451 |
452 |
453 | GO
454 | /****** Object: StoredProcedure [dbo].[GetVideoFrames] Script Date: 1/12/2016 1:42:58 AM ******/
455 | SET ANSI_NULLS ON
456 | GO
457 | SET QUOTED_IDENTIFIER ON
458 | GO
459 |
460 | CREATE PROCEDURE [dbo].[GetVideoFrames]
461 | @VideoId int
462 | AS
463 |
464 | BEGIN
465 |
466 | SELECT f.*
467 | FROM Jobs j
468 | JOIN Frames f
469 | ON j.Id = f.JobId
470 | WHERE j.VideoId = @VideoId
471 | ORDER BY f.FrameIndex ASC
472 |
473 | END
474 |
475 |
476 |
477 |
478 |
479 | GO
480 | /****** Object: StoredProcedure [dbo].[GetVideoFramesByJob] Script Date: 1/12/2016 1:42:58 AM ******/
481 | SET ANSI_NULLS ON
482 | GO
483 | SET QUOTED_IDENTIFIER ON
484 | GO
485 |
486 | CREATE PROCEDURE [dbo].[GetVideoFramesByJob]
487 | @JobId int
488 | AS
489 |
490 | BEGIN
491 |
492 | SELECT f.*
493 | FROM Jobs j
494 | JOIN Frames f
495 | ON j.Id = f.JobId
496 | WHERE j.Id = @JobId
497 | ORDER BY f.FrameIndex ASC
498 |
499 | END
500 |
501 |
502 |
503 |
504 |
505 | GO
506 | /****** Object: StoredProcedure [dbo].[GetVideos] Script Date: 1/12/2016 1:42:58 AM ******/
507 | SET ANSI_NULLS ON
508 | GO
509 | SET QUOTED_IDENTIFIER ON
510 | GO
511 | CREATE PROCEDURE [dbo].[GetVideos]
512 | @udtVideoLabels UDT_VideoLabelsList READONLY,
513 | @Unassigned bit = 0
514 | AS
515 |
516 | BEGIN
517 |
518 |
519 | DECLARE @QRY VARCHAR(4000)
520 | SET @QRY = 'SELECT v.*,
521 | stuff(
522 | ( SELECT '',''+ l.Name
523 | FROM VideoLabels vl
524 | JOIN Labels l
525 | ON vl.LabelId = l.Id
526 | AND vl.VideoId = v.Id
527 | FOR XML PATH('''')
528 | ),1,1,'''') AS Labels
529 | FROM (SELECT * FROM Videos) v '
530 |
531 | IF @Unassigned = 1
532 | BEGIN
533 | SET @QRY = @QRY + 'LEFT JOIN Jobs j ON j.VideoId = v.Id '
534 | END
535 |
536 |
537 | DECLARE @Cursor CURSOR;
538 | DECLARE @LabelId int
539 |
540 | SET @Cursor = CURSOR FOR
541 | select LabelId from @udtVideoLabels
542 |
543 | OPEN @Cursor
544 | FETCH NEXT FROM @Cursor
545 | INTO @LabelId
546 |
547 | DECLARE @I INT = 1
548 | WHILE @@FETCH_STATUS = 0
549 | BEGIN
550 |
551 | SET @QRY = @QRY + 'JOIN VideoLabels vl' + CAST(@I AS VARCHAR(10))
552 | + ' ON v.Id = vl' + CAST(@I AS VARCHAR(10)) + '.VideoId AND vl'
553 | + CAST(@I AS VARCHAR(10)) + '.LabelId =' + CAST(@LabelId AS VARCHAR(10)) + ' '
554 | FETCH NEXT FROM @Cursor
555 | INTO @LabelId
556 |
557 | SET @I = @I + 1
558 | END;
559 |
560 | CLOSE @Cursor ;
561 | DEALLOCATE @Cursor;
562 |
563 | IF @Unassigned = 1
564 | BEGIN
565 | SET @QRY = @QRY + ' WHERE j.VideoId IS NULL'
566 | END
567 |
568 | --SELECT @QRY
569 | EXEC (@QRY)
570 |
571 |
572 | END
573 |
574 |
575 |
576 |
577 | GO
578 | /****** Object: StoredProcedure [dbo].[GetVideosByLabels] Script Date: 1/12/2016 1:42:58 AM ******/
579 | SET ANSI_NULLS ON
580 | GO
581 | SET QUOTED_IDENTIFIER ON
582 | GO
583 | CREATE PROCEDURE [dbo].[GetVideosByLabels]
584 | @udtVideoLabels UDT_VideoLabelsList READONLY
585 | AS
586 |
587 | BEGIN
588 |
589 |
590 | DECLARE @QRY VARCHAR(4000)
591 | SET @QRY = 'SELECT v.*,
592 | stuff(
593 | ( SELECT '',''+ l.Name
594 | FROM VideoLabels vl
595 | JOIN Labels l
596 | ON vl.LabelId = l.Id
597 | AND vl.VideoId = v.Id
598 | FOR XML PATH('''')
599 | ),1,1,'''') AS Labels
600 | FROM (SELECT * FROM Videos) v '
601 |
602 |
603 | DECLARE @Cursor CURSOR;
604 | DECLARE @LabelId int
605 |
606 | SET @Cursor = CURSOR FOR
607 | select LabelId from @udtVideoLabels
608 |
609 | OPEN @Cursor
610 | FETCH NEXT FROM @Cursor
611 | INTO @LabelId
612 |
613 | DECLARE @I INT = 1
614 | WHILE @@FETCH_STATUS = 0
615 | BEGIN
616 |
617 | SET @QRY = @QRY + 'JOIN VideoLabels vl' + CAST(@I AS VARCHAR(10))
618 | + ' ON v.Id = vl' + CAST(@I AS VARCHAR(10)) + '.VideoId AND vl'
619 | + CAST(@I AS VARCHAR(10)) + '.LabelId =' + CAST(@LabelId AS VARCHAR(10)) + ' '
620 | FETCH NEXT FROM @Cursor
621 | INTO @LabelId
622 |
623 | SET @I = @I + 1
624 | END;
625 |
626 | CLOSE @Cursor ;
627 | DEALLOCATE @Cursor;
628 |
629 | --SELECT @QRY
630 | EXEC (@QRY)
631 |
632 |
633 | END
634 |
635 |
636 |
637 |
638 | GO
639 | /****** Object: StoredProcedure [dbo].[UpdateJobStatus] Script Date: 1/12/2016 1:42:58 AM ******/
640 | SET ANSI_NULLS ON
641 | GO
642 | SET QUOTED_IDENTIFIER ON
643 | GO
644 |
645 | CREATE PROCEDURE [dbo].[UpdateJobStatus]
646 | @Id int = -1,
647 | @UserId int = -1,
648 | @StatusId tinyint
649 | AS
650 | BEGIN
651 |
652 | SET NOCOUNT ON;
653 |
654 |
655 | if @UserId != -1 AND @StatusId=3 /* APPROVED */
656 | BEGIN
657 | UPDATE Jobs
658 | SET StatusId = @StatusId, ReviewedById = @UserId
659 | WHERE Id = @Id
660 | END
661 | ELSE
662 | BEGIN
663 | UPDATE Jobs
664 | SET StatusId = @StatusId, ReviewedById = NULL
665 | WHERE Id = @Id
666 | END
667 |
668 | END
669 |
670 |
671 | GO
672 | /****** Object: StoredProcedure [dbo].[UpdateVideoUploaded] Script Date: 1/12/2016 1:42:58 AM ******/
673 | SET ANSI_NULLS ON
674 | GO
675 | SET QUOTED_IDENTIFIER ON
676 | GO
677 |
678 | CREATE PROCEDURE [dbo].[UpdateVideoUploaded]
679 | @Id int = -1
680 | AS
681 | BEGIN
682 |
683 | UPDATE [Videos]
684 | SET VideoUploaded = 1
685 | WHERE Id = @Id
686 | END
687 |
688 |
689 |
690 | GO
691 | /****** Object: StoredProcedure [dbo].[UpsertFrame] Script Date: 1/12/2016 1:42:58 AM ******/
692 | SET ANSI_NULLS ON
693 | GO
694 | SET QUOTED_IDENTIFIER ON
695 | GO
696 | CREATE PROCEDURE [dbo].[UpsertFrame]
697 | @JobId int,
698 | @FrameIndex bigint,
699 | @TagsJson ntext
700 | AS
701 | BEGIN
702 |
703 | SET NOCOUNT ON;
704 |
705 | MERGE
706 | Frames
707 | USING (
708 | VALUES (@JobId, @FrameIndex, @TagsJson)
709 | ) AS source (JobId, FrameIndex, TagsJson)
710 | ON Frames.JobId = source.JobId
711 | AND Frames.FrameIndex = source.FrameIndex
712 | WHEN MATCHED THEN
713 | UPDATE SET TagsJson = source.TagsJson
714 | WHEN NOT MATCHED THEN
715 | INSERT (JobId, FrameIndex, TagsJson)
716 | VALUES (JobId, FrameIndex, TagsJson)
717 | ; --A MERGE statement must be terminated by a semi-colon (;).
718 |
719 | END
720 |
721 |
722 |
723 | GO
724 | /****** Object: StoredProcedure [dbo].[UpsertJob] Script Date: 1/12/2016 1:42:58 AM ******/
725 | SET ANSI_NULLS ON
726 | GO
727 | SET QUOTED_IDENTIFIER ON
728 | GO
729 |
730 | CREATE PROCEDURE [dbo].[UpsertJob]
731 | -- Add the parameters for the stored procedure here
732 | @Id int = -1,
733 | @VideoId int,
734 | @UserId int,
735 | @Description nvarchar(1024),
736 | @CreatedById int,
737 | @StatusId tinyint,
738 | @ConfigJson ntext,
739 | @JobId int OUTPUT
740 | AS
741 | BEGIN
742 | -- SET NOCOUNT ON added to prevent extra result sets from
743 | -- interfering with SELECT statements.
744 | SET NOCOUNT ON;
745 |
746 | BEGIN TRANSACTION T1
747 |
748 |
749 | IF @Id IS NOT NULL AND EXISTS (
750 | SELECT * FROM Jobs
751 | WHERE Id = @Id
752 | )
753 | BEGIN
754 | UPDATE [Jobs]
755 | SET VideoId = @VideoId
756 | ,UserId = @UserId
757 | ,[Description] = @Description
758 | ,CreatedById = @CreatedById
759 | ,StatusId = @StatusId
760 | ,ConfigJson = @ConfigJson
761 | WHERE Id = @Id
762 |
763 | SET @JobId = @Id
764 | END
765 | ELSE
766 | BEGIN
767 |
768 | INSERT INTO [dbo].[Jobs]
769 | ([VideoId]
770 | ,[UserId]
771 | ,[Description]
772 | ,[CreatedById]
773 | ,[StatusId]
774 | ,[CreateDate]
775 | ,[ConfigJson]
776 | )
777 | VALUES
778 | (@VideoId
779 | ,@UserId
780 | ,@Description
781 | ,@CreatedById
782 | ,@StatusId
783 | ,GETDATE()
784 | ,@ConfigJson)
785 | END
786 |
787 | SET @JobId = (SELECT Id FROM Jobs WHERE VideoId = @VideoId AND UserId = @UserId)
788 |
789 | COMMIT TRANSACTION T1
790 |
791 | END
792 |
793 |
794 |
795 |
796 | GO
797 | /****** Object: StoredProcedure [dbo].[UpsertUser] Script Date: 1/12/2016 1:42:58 AM ******/
798 | SET ANSI_NULLS ON
799 | GO
800 | SET QUOTED_IDENTIFIER ON
801 | GO
802 |
803 | CREATE PROCEDURE [dbo].[UpsertUser]
804 | @Id int = -1,
805 | @Name nvarchar(50),
806 | @Email varchar(100),
807 | @RoleId tinyint,
808 | @UserId int OUTPUT
809 | AS
810 | BEGIN
811 |
812 | IF @Id IS NOT NULL AND EXISTS (
813 | SELECT * FROM Users
814 | WHERE Id = @Id
815 | )
816 | BEGIN
817 | UPDATE [Users]
818 | SET Name = @Name
819 | ,Email = @Email
820 | ,RoleId = @RoleId
821 | WHERE Id = @Id
822 |
823 | SET @UserId = @Id
824 | END
825 | ELSE
826 | BEGIN
827 |
828 | INSERT INTO [dbo].[Users]
829 | ([Name]
830 | ,[Email]
831 | ,[RoleId])
832 | VALUES
833 | (@Name
834 | ,@Email
835 | ,@RoleId)
836 |
837 | SET @UserId = (SELECT @@IDENTITY)
838 | END
839 |
840 | END
841 |
842 |
843 |
844 |
845 | GO
846 | /****** Object: StoredProcedure [dbo].[UpsertVideo] Script Date: 1/12/2016 1:42:58 AM ******/
847 | SET ANSI_NULLS ON
848 | GO
849 | SET QUOTED_IDENTIFIER ON
850 | GO
851 |
852 |
853 | CREATE PROCEDURE [dbo].[UpsertVideo]
854 | -- Add the parameters for the stored procedure here
855 | @Id int = -1,
856 | @Name nvarchar(100),
857 | @Width int,
858 | @Height int,
859 | @DurationSeconds real,
860 | @FramesPerSecond real,
861 | @VideoJson ntext = NULL,
862 | @udtLabels UDT_LabelsList READONLY,
863 | @VideoId int OUTPUT
864 | AS
865 | BEGIN
866 | -- SET NOCOUNT ON added to prevent extra result sets from
867 | -- interfering with SELECT statements.
868 | SET NOCOUNT ON;
869 |
870 | BEGIN TRANSACTION T1
871 |
872 | IF @Id IS NOT NULL AND EXISTS (
873 | SELECT * FROM Videos
874 | WHERE Id = @Id
875 | )
876 | BEGIN
877 | UPDATE [Videos]
878 | SET Name = @Name
879 | ,Width = @Width
880 | ,Height = @Height
881 | ,DurationSeconds = @DurationSeconds
882 | ,FramesPerSecond = @FramesPerSecond
883 | ,VideoJson = @VideoJson
884 | WHERE Id = @Id
885 |
886 | SET @VideoId = @Id
887 | END
888 | ELSE
889 | BEGIN
890 |
891 | INSERT INTO [dbo].[Videos]
892 | ([Name]
893 | ,[Width]
894 | ,[Height]
895 | ,[DurationSeconds]
896 | ,[FramesPerSecond]
897 | ,[VideoJson])
898 | VALUES
899 | (@Name
900 | ,@Width
901 | ,@Height
902 | ,@DurationSeconds
903 | ,@FramesPerSecond
904 | ,@VideoJson)
905 |
906 |
907 | SET @VideoId = (SELECT @@IDENTITY)
908 | END
909 |
910 | DELETE FROM VideoLabels WHERE VideoId = @VideoId
911 |
912 | -- updating labels
913 | DECLARE @Cursor CURSOR;
914 | DECLARE @Label varchar(50)
915 | DECLARE @LabelId int
916 |
917 | SET @Cursor = CURSOR FOR
918 | select Name from @udtLabels
919 |
920 | OPEN @Cursor
921 | FETCH NEXT FROM @Cursor
922 | INTO @Label
923 |
924 | WHILE @@FETCH_STATUS = 0
925 | BEGIN
926 |
927 | select @Label
928 | SET @LabelId = (SELECT Id FROM Labels WHERE Name = @Label)
929 | IF @LabelId IS NULL
930 | BEGIN
931 | INSERT INTO Labels VALUES (@Label)
932 | SET @LabelId = (SELECT @@IDENTITY)
933 | END
934 |
935 | INSERT INTO VideoLabels VALUES (@VideoId, @LabelId)
936 |
937 | FETCH NEXT FROM @Cursor
938 | INTO @Label
939 |
940 | END;
941 |
942 | CLOSE @Cursor ;
943 | DEALLOCATE @Cursor;
944 |
945 | COMMIT TRANSACTION T1
946 |
947 | END
948 |
949 | GO
950 |
951 | INSERT INTO [dbo].[Roles] ([Id], [Name], [Description]) VALUES (1, 'Editor', 'Edit videos')
952 | GO
953 |
954 | INSERT INTO [dbo].[Roles] ([Id] ,[Name] ,[Description]) VALUES (2 ,'Admin' ,'Administrator')
955 | GO
956 |
957 | INSERT INTO [dbo].[JobStatus] ([Id] ,[Name] ,[Description]) VALUES (1 ,'Active' ,'Job is Active')
958 | GO
959 |
960 | INSERT INTO [dbo].[JobStatus] ([Id] ,[Name] ,[Description]) VALUES (2 ,'Pending' ,'Job is Pending')
961 | GO
962 |
963 | INSERT INTO [dbo].[JobStatus] ([Id] ,[Name] ,[Description]) VALUES (3 ,'Approved' ,'Job is Approved')
964 | GO
965 |
966 |
967 |
968 |
--------------------------------------------------------------------------------