├── .gitignore ├── definitions ├── users.rest ├── employees.rest └── employees-variant.rest ├── .env ├── scripts ├── connections.sql └── foo_db.sql ├── api ├── users.js ├── employees-variant.js └── employees.js ├── package.json ├── README.md ├── index.js └── data-access.js /.gitignore: -------------------------------------------------------------------------------- 1 | node_modules -------------------------------------------------------------------------------- /definitions/users.rest: -------------------------------------------------------------------------------- 1 | #### User API 2 | 3 | #### Get All Users 4 | GET http://localhost:3000/api/users -------------------------------------------------------------------------------- /.env: -------------------------------------------------------------------------------- 1 | # Application 2 | NODE_ENV=development 3 | PORT=3000 4 | 5 | # Database 6 | SQL_DRIVER=SQL Server 7 | SQL_SERVER=DESKTOP-6AQPB1S\SQLEXPRESS 8 | SQL_DATABASE=foo_db 9 | SQL_UID=sa 10 | SQL_PWD=password_123 -------------------------------------------------------------------------------- /scripts/connections.sql: -------------------------------------------------------------------------------- 1 | -- queries to check open connection for a db 2 | -- https://stackoverflow.com/questions/1248423/how-do-i-see-active-sql-server-connections 3 | 4 | -- shows count of open connections 5 | SELECT 6 | DB_NAME(dbid) as DBName, 7 | COUNT(dbid) as NumberOfConnections, 8 | loginame as LoginName 9 | FROM 10 | sys.sysprocesses 11 | WHERE 12 | dbid > 0 13 | GROUP BY 14 | dbid, loginame; 15 | 16 | -- show details 17 | EXEC sp_who 18 | EXEC sp_who2 -------------------------------------------------------------------------------- /api/users.js: -------------------------------------------------------------------------------- 1 | const express = require('express') 2 | const DataAccess = require('../data-access') 3 | 4 | const router = express.Router(); 5 | 6 | router.get('/', async (req, res) => { 7 | try { 8 | const result = await DataAccess.query(`SELECT * FROM [User] ORDER BY Id DESC`); 9 | const users = result.recordset; 10 | 11 | res.json(users); 12 | } catch (error) { 13 | console.log(error) 14 | res.status(500).json(error); 15 | } 16 | }); 17 | 18 | module.exports = router; -------------------------------------------------------------------------------- /package.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "mssql-api", 3 | "version": "1.0.0", 4 | "description": "NodeJS with MSSQL", 5 | "main": "index.js", 6 | "scripts": { 7 | "start": "nodemon index", 8 | "test": "echo \"Error: no test specified\" && exit 1" 9 | }, 10 | "keywords": [ 11 | "NodeJS", 12 | "MSSQL" 13 | ], 14 | "author": "Zaki Mohammed", 15 | "license": "ISC", 16 | "dependencies": { 17 | "dotenv": "^8.2.0", 18 | "express": "^4.17.1", 19 | "mssql": "^6.3.0" 20 | }, 21 | "devDependencies": { 22 | "nodemon": "^2.0.6" 23 | } 24 | } 25 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Teaming up with NodeJS and SQL Server 2 | 3 | Making a smooth connection between NodeJS and MSSQL, and perform the decade old tradition (CRUD). 4 | 5 | Check out the CodeOmelet blog post for this project. 6 | 7 | Link: http://codeomelet.com/posts/teaming-up-with-nodejs-and-sql-server 8 | 9 | # Calling Stored Procedure with NodeJS and MSSQL 10 | 11 | Highlighting most of the common scenarios we deal with while calling stored procs with NodeJS and MSSQL. 12 | 13 | Check out the CodeOmelet blog post for this project. 14 | 15 | Link: http://codeomelet.com/posts/calling-stored-procedure-with-nodejs-and-mssql -------------------------------------------------------------------------------- /index.js: -------------------------------------------------------------------------------- 1 | const express = require('express') 2 | const dotenv = require('dotenv') 3 | 4 | const app = express(); 5 | 6 | dotenv.config(); 7 | 8 | app.use(express.json()); 9 | app.use(express.urlencoded({ extended: false })); 10 | 11 | app.get('/', (req, res) => { 12 | res.send('

🤖 Teaming up with NodeJS and SQL Server

'); 13 | }); 14 | 15 | app.use('/api/employees', require('./api/employees')); 16 | app.use('/api/employees-variant', require('./api/employees-variant')); 17 | app.use('/api/users', require('./api/users')); 18 | 19 | app.listen(process.env.PORT, () => { 20 | console.log(`Server started running on ${process.env.PORT} for ${process.env.NODE_ENV}`); 21 | }); 22 | -------------------------------------------------------------------------------- /definitions/employees.rest: -------------------------------------------------------------------------------- 1 | #### Employee API 2 | 3 | #### Get Employees Status 4 | GET http://localhost:3000/api/employees/status 5 | 6 | #### Search Employees 7 | GET http://localhost:3000/api/employees/search?name=jo 8 | 9 | #### Employee Summary 10 | GET http://localhost:3000/api/employees/summary 11 | 12 | #### Add Many Employees 13 | POST http://localhost:3000/api/employees/many 14 | content-type: application/json 15 | 16 | [ 17 | { 18 | "Id": 0, 19 | "Code": "CT8100", 20 | "Name": "Bruce Banner", 21 | "Job": "Salesman", 22 | "Salary": 20000, 23 | "Department": "Sales" 24 | }, 25 | { 26 | "Id": 0, 27 | "Code": "CT8200", 28 | "Name": "Clint", 29 | "Job": "Salesman", 30 | "Salary": 20000, 31 | "Department": "Sales" 32 | } 33 | ] 34 | 35 | #### Get All Employees 36 | GET http://localhost:3000/api/employees 37 | 38 | #### Get Employee 39 | GET http://localhost:3000/api/employees/1 40 | 41 | #### Add Employee 42 | POST http://localhost:3000/api/employees 43 | content-type: application/json 44 | 45 | { 46 | "Id": 0, 47 | "Code": "CT8000", 48 | "Name": "Bucky Barns", 49 | "Job": "Manager", 50 | "Salary": 30000, 51 | "Department": "Operations" 52 | } 53 | 54 | #### Update Employee 55 | PUT http://localhost:3000/api/employees/32 56 | content-type: application/json 57 | 58 | { 59 | "Id": 32, 60 | "Code": "CT9000", 61 | "Name": "Bucky Barns", 62 | "Job": "Manager", 63 | "Salary": 30000, 64 | "Department": "Operations" 65 | } 66 | 67 | #### Delete Employee 68 | DELETE http://localhost:3000/api/employees/32 -------------------------------------------------------------------------------- /definitions/employees-variant.rest: -------------------------------------------------------------------------------- 1 | #### Employee Variant API 2 | 3 | #### Get Employees Status 4 | GET http://localhost:3000/api/employees-variant/status 5 | 6 | #### Search Employees 7 | GET http://localhost:3000/api/employees-variant/search?name=jo 8 | 9 | #### Employee Summary 10 | GET http://localhost:3000/api/employees-variant/summary 11 | 12 | #### Add Many Employees 13 | POST http://localhost:3000/api/employees-variant/many 14 | content-type: application/json 15 | 16 | [ 17 | { 18 | "Id": 0, 19 | "Code": "CT8100", 20 | "Name": "Bruce Banner", 21 | "Job": "Salesman", 22 | "Salary": 20000, 23 | "Department": "Sales" 24 | }, 25 | { 26 | "Id": 0, 27 | "Code": "CT8200", 28 | "Name": "Clint", 29 | "Job": "Salesman", 30 | "Salary": 20000, 31 | "Department": "Sales" 32 | } 33 | ] 34 | 35 | #### Get All Employees 36 | GET http://localhost:3000/api/employees-variant 37 | 38 | #### Get Employee 39 | GET http://localhost:3000/api/employees-variant/1 40 | 41 | #### Add Employee 42 | POST http://localhost:3000/api/employees-variant 43 | content-type: application/json 44 | 45 | { 46 | "Id": 0, 47 | "Code": "CT8000", 48 | "Name": "Bucky Barns", 49 | "Job": "Manager", 50 | "Salary": 30000, 51 | "Department": "Operations" 52 | } 53 | 54 | #### Update Employee 55 | PUT http://localhost:3000/api/employees-variant/49 56 | content-type: application/json 57 | 58 | { 59 | "Id": 49, 60 | "Code": "CT9000", 61 | "Name": "Berry Allen", 62 | "Job": "Manager", 63 | "Salary": 20000, 64 | "Department": "Operations" 65 | } 66 | 67 | #### Delete Employee 68 | DELETE http://localhost:3000/api/employees-variant/58 -------------------------------------------------------------------------------- /data-access.js: -------------------------------------------------------------------------------- 1 | const mssql = require('mssql') 2 | 3 | let pool; 4 | 5 | const poolConfig = () => ({ 6 | driver: process.env.SQL_DRIVER, 7 | server: process.env.SQL_SERVER, 8 | database: process.env.SQL_DATABASE, 9 | user: process.env.SQL_UID, 10 | password: process.env.SQL_PWD, 11 | options: { 12 | encrypt: false, 13 | enableArithAbort: false 14 | } 15 | }); 16 | 17 | const fetchParams = entity => { 18 | const params = []; 19 | for (const key in entity) { 20 | if (entity.hasOwnProperty(key)) { 21 | const value = entity[key]; 22 | params.push({ 23 | name: key, 24 | value 25 | }); 26 | } 27 | } 28 | return params; 29 | }; 30 | 31 | const assignParams = (request, inputs, outputs) => { 32 | [inputs, outputs].forEach((params, index) => { 33 | const operation = index === 0 ? 'input' : 'output'; 34 | params.forEach(param => { 35 | if (param.type) { 36 | request[operation](param.name, param.type, param.value); 37 | } else { 38 | request[operation](param.name, param.value); 39 | } 40 | }); 41 | }); 42 | }; 43 | 44 | const run = async (name, command, inputs = [], outputs = []) => { 45 | await connect(); 46 | const request = pool.request(); 47 | assignParams(request, inputs, outputs); 48 | return request[name](command); 49 | }; 50 | 51 | const connect = async () => { 52 | if (!pool) { 53 | pool = new mssql.ConnectionPool(poolConfig()); 54 | } 55 | if (!pool.connected) { 56 | await pool.connect(); 57 | } 58 | }; 59 | 60 | const query = async (command, inputs = [], outputs = []) => { 61 | return run('query', command, inputs, outputs); 62 | }; 63 | 64 | const queryEntity = async (command, entity, outputs = []) => { 65 | const inputs = fetchParams(entity); 66 | return run('query', command, inputs, outputs); 67 | }; 68 | 69 | const execute = async (command, inputs = [], outputs = []) => { 70 | return run('execute', command, inputs, outputs); 71 | }; 72 | 73 | const executeEntity = async (command, entity, outputs = []) => { 74 | const inputs = fetchParams(entity); 75 | return run('execute', command, inputs, outputs); 76 | }; 77 | 78 | const generateTable = (columns, entities) => { 79 | const table = new mssql.Table(); 80 | 81 | columns.forEach(column => { 82 | if (column && typeof column === 'object' && column.name && column.type) { 83 | if (column.hasOwnProperty('options')) { 84 | table.columns.add(column.name, column.type, column.options); 85 | } else { 86 | table.columns.add(column.name, column.type); 87 | } 88 | } 89 | }); 90 | 91 | entities.forEach(entity => { 92 | table.rows.add(...columns.map(i => entity[i.name])); 93 | }); 94 | 95 | return table; 96 | }; 97 | 98 | module.exports = { 99 | pool, 100 | mssql, 101 | connect, 102 | query, 103 | queryEntity, 104 | execute, 105 | executeEntity, 106 | generateTable 107 | }; -------------------------------------------------------------------------------- /api/employees-variant.js: -------------------------------------------------------------------------------- 1 | const express = require('express') 2 | const dataAccess = require('../data-access') 3 | 4 | const router = express.Router(); 5 | 6 | router.get('/search', async (req, res) => { 7 | try { 8 | const result = await dataAccess.execute(`SearchEmployee`, [ 9 | { name: 'Name', value: req.query.name } 10 | ]); 11 | const employees = result.recordset; 12 | 13 | res.json(employees); 14 | } catch (error) { 15 | res.status(500).json(error); 16 | } 17 | }); 18 | router.get('/status', async (req, res) => { 19 | try { 20 | const result = await dataAccess.execute(`GetEmployeesStatus`, [], [ 21 | { name: 'Count', value: 0 }, 22 | { name: 'Max', value: 0 }, 23 | { name: 'Min', value: 0 }, 24 | { name: 'Average', value: 0 }, 25 | { name: 'Sum', value: 0 }, 26 | ]); 27 | const status = { 28 | Count: +result.output.Count, 29 | Max: +result.output.Max, 30 | Min: +result.output.Min, 31 | Average: +result.output.Average, 32 | Sum: +result.output.Sum 33 | }; 34 | 35 | res.json(status); 36 | } catch (error) { 37 | res.status(500).json(error); 38 | } 39 | }); 40 | router.get('/summary', async (req, res) => { 41 | try { 42 | const result = await dataAccess.execute(`GetSalarySummary`); 43 | const summary = { 44 | Department: result.recordsets[0], 45 | Job: result.recordsets[1], 46 | }; 47 | 48 | res.json(summary); 49 | } catch (error) { 50 | res.status(500).json(error); 51 | } 52 | }); 53 | router.post('/many', async (req, res) => { 54 | try { 55 | const employees = req.body; 56 | const employeesTable = dataAccess.generateTable([ 57 | { name: 'Code', type: dataAccess.mssql.TYPES.VarChar(50) }, 58 | { name: 'Name', type: dataAccess.mssql.TYPES.VarChar(50) }, 59 | { name: 'Job', type: dataAccess.mssql.TYPES.VarChar(50) }, 60 | { name: 'Salary', type: dataAccess.mssql.TYPES.Int }, 61 | { name: 'Department', type: dataAccess.mssql.TYPES.VarChar(50) } 62 | ], employees); 63 | 64 | const result = await dataAccess.execute(`AddEmployees`, [ 65 | { name: 'Employees', value: employeesTable } 66 | ]); 67 | const newEmployees = result.recordset; 68 | res.json(newEmployees); 69 | } catch (error) { 70 | console.log(error) 71 | res.status(500).json(error); 72 | } 73 | }); 74 | 75 | router.get('/:id', async (req, res) => { 76 | try { 77 | const result = await dataAccess.query(`SELECT * FROM Employee WHERE Id = @Id`, [ 78 | { name: 'Id', value: req.params.id } 79 | ]); 80 | const employee = result.recordset.length ? result.recordset[0] : null; 81 | 82 | if (employee) { 83 | res.json(employee); 84 | } else { 85 | res.status(404).json({ 86 | message: 'Record not found' 87 | }); 88 | } 89 | } catch (error) { 90 | res.status(500).json(error); 91 | } 92 | }); 93 | router.get('/', async (req, res) => { 94 | try { 95 | const result = await dataAccess.query(`SELECT * FROM Employee ORDER BY Id DESC`); 96 | const employees = result.recordset; 97 | 98 | res.json(employees); 99 | } catch (error) { 100 | console.log(error) 101 | res.status(500).json(error); 102 | } 103 | }); 104 | router.post('/', async (req, res) => { 105 | try { 106 | /* 107 | // passing input as arrays 108 | const result = await DataAccess.query( 109 | ` 110 | INSERT INTO Employee (Code, Salary, Job, Department, Name) 111 | OUTPUT inserted.Id 112 | VALUES (@Code, @Salary, @Job, @Department, @Name); 113 | `, 114 | [ 115 | { name: 'Code', value: req.body.Code }, 116 | { name: 'Salary', value: req.body.Salary }, 117 | { name: 'Job', value: req.body.Job }, 118 | { name: 'Department', value: req.body.Department }, 119 | { name: 'Name', value: req.body.Name }, 120 | ] 121 | ); 122 | */ 123 | 124 | // passing input as entity 125 | const result = await dataAccess.queryEntity( 126 | ` 127 | INSERT INTO Employee (Code, Salary, Job, Department, Name) 128 | OUTPUT inserted.Id 129 | VALUES (@Code, @Salary, @Job, @Department, @Name); 130 | `, req.body 131 | ); 132 | const employee = req.body; 133 | employee.Id = result.recordset[0].Id; 134 | res.json(employee); 135 | } catch (error) { 136 | res.status(500).json(error); 137 | } 138 | }); 139 | router.put('/:id', async (req, res) => { 140 | try { 141 | if (+req.params.id !== req.body.Id) { 142 | res.status(400).json({ 143 | message: 'Mismatched identity' 144 | }); 145 | return; 146 | } 147 | 148 | const result = await dataAccess.query(`SELECT * FROM Employee WHERE Id = @Id`, [ 149 | { name: 'Id', value: req.params.id } 150 | ]); 151 | 152 | let employee = result.recordset.length ? result.recordset[0] : null; 153 | if (employee) { 154 | await dataAccess.queryEntity( 155 | ` 156 | UPDATE Employee SET 157 | Code = @Code, 158 | Salary = @Salary, 159 | Job = @Job, 160 | Department = @Department, 161 | Name = @Name 162 | WHERE Id = @Id; 163 | `, req.body 164 | ); 165 | 166 | employee = { ...employee, ...req.body }; 167 | 168 | res.json(employee); 169 | } else { 170 | res.status(404).json({ 171 | message: 'Record not found' 172 | }); 173 | } 174 | } catch (error) { 175 | res.status(500).json(error); 176 | } 177 | }); 178 | router.delete('/:id', async (req, res) => { 179 | try { 180 | const result = await dataAccess.query(`SELECT * FROM Employee WHERE Id = @Id`, [ 181 | { name: 'Id', value: req.params.id } 182 | ]); 183 | 184 | let employee = result.recordset.length ? result.recordset[0] : null; 185 | if (employee) { 186 | await dataAccess.query(`DELETE FROM Employee WHERE Id = @Id;`, [ 187 | { name: 'Id', value: req.params.id } 188 | ]); 189 | res.json({}); 190 | } else { 191 | res.status(404).json({ 192 | message: 'Record not found' 193 | }); 194 | } 195 | } catch (error) { 196 | res.status(500).json(error); 197 | } 198 | }); 199 | 200 | module.exports = router; -------------------------------------------------------------------------------- /scripts/foo_db.sql: -------------------------------------------------------------------------------- 1 | /****** Object: Table [dbo].[Employee] Script Date: 9/2/2020 2:15:47 AM ******/ 2 | SET ANSI_NULLS ON 3 | GO 4 | SET QUOTED_IDENTIFIER ON 5 | GO 6 | CREATE TABLE [dbo].[Employee]( 7 | [Id] [int] IDENTITY(1,1) NOT NULL, 8 | [Code] [varchar](50) NOT NULL, 9 | [Name] [varchar](50) NULL, 10 | [Job] [varchar](50) NULL, 11 | [Salary] [int] NULL, 12 | [Department] [varchar](50) NULL, 13 | CONSTRAINT [PK_Employee] PRIMARY KEY CLUSTERED 14 | ( 15 | [Id] ASC 16 | )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] 17 | ) ON [PRIMARY] 18 | GO 19 | SET IDENTITY_INSERT [dbo].[Employee] ON 20 | 21 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (1, N'CT7207', N'Bently Smith', N'Manager', 40000, N'Operations') 22 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (2, N'CT7210', N'Isla Morris', N'Director', 80000, N'Operations') 23 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (3, N'CT7202', N'Allen Green', N'Salesman', 15000, N'Sales') 24 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (4, N'CT7208', N'Xavier Campbell', N'Analyst', 50000, N'Research') 25 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (5, N'CT7209', N'Ethan Kumar', N'Analyst', 50000, N'Research') 26 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (6, N'CT7201', N'John Marshal', N'Clerk', 20000, N'Accounting') 27 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (7, N'CT7205', N'Ethan Almaas', N'Salesman', 15000, N'Sales') 28 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (8, N'CT7211', N'Natalie Robinson', N'Salesman', 15000, N'Sales') 29 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (9, N'CT7212', N'Earl Rose', N'Salesman', 15000, N'Sales') 30 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (10, N'CT7206', N'Ilija Seifert', N'Clerk', 20000, N'Accounting') 31 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (11, N'CT7204', N'Annette Burke', N'Clerk', 20000, N'Accounting') 32 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (12, N'CT7203', N'Fernando Gordon', N'Salesman', 15000, N'Sales') 33 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (13, N'CT7213', N'Catherine Foster', N'Salesman', 15000, N'Sales') 34 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (14, N'CT7207', N'Josh', N'Manager', 40000, N'Operations') 35 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (15, N'CT7207', N'Paul', N'Manager', 40000, N'Operations') 36 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (18, N'CT7207', N'Jim Wong', N'Manager', 40000, N'Operations') 37 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (21, N'CT7207', N'Harry Potter', N'Manager', 30000, N'Operations') 38 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (23, N'CT7207', N'Tony Stark', N'Manager', 20000, N'Operations') 39 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (24, N'CT7207', N'Steve Rogers', N'Manager', 20000, N'Operations') 40 | INSERT [dbo].[Employee] ([Id], [Code], [Name], [Job], [Salary], [Department]) VALUES (25, N'CT7547', N'Tom Holland', N'Manager', 20000, N'Operations') 41 | SET IDENTITY_INSERT [dbo].[Employee] OFF 42 | GO 43 | 44 | /****** Object: StoredProcedure [dbo].[SearchEmployee] Script Date: 12/28/2020 6:53:18 PM ******/ 45 | SET ANSI_NULLS ON 46 | GO 47 | 48 | SET QUOTED_IDENTIFIER ON 49 | GO 50 | -- ============================================= 51 | -- Author: Zaki Mohammed 52 | -- Create date: 8:05 PM 5/13/2020 53 | -- Description: Search employee by name 54 | -- ============================================= 55 | CREATE PROCEDURE [dbo].[SearchEmployee] 56 | @Name VARCHAR(100) 57 | AS 58 | BEGIN 59 | SELECT * FROM Employee WHERE LOWER(Name) LIKE '%' + LOWER(@Name) + '%' 60 | END 61 | GO 62 | 63 | /****** Object: StoredProcedure [dbo].[GetEmployeesStatus] Script Date: 12/28/2020 6:53:52 PM ******/ 64 | SET ANSI_NULLS ON 65 | GO 66 | 67 | SET QUOTED_IDENTIFIER ON 68 | GO 69 | -- ============================================= 70 | -- Author: Zaki Mohammed 71 | -- Create date: 1:44 AM 9/2/2020 72 | -- Description: Get employee records current status 73 | -- ============================================= 74 | CREATE PROCEDURE [dbo].[GetEmployeesStatus] 75 | @Count INT OUTPUT, 76 | @Max INT OUTPUT, 77 | @Min INT OUTPUT, 78 | @Average INT OUTPUT, 79 | @Sum INT OUTPUT 80 | AS 81 | BEGIN 82 | SELECT @Count = COUNT(1), 83 | @Max = MAX(Salary), 84 | @Min = MIN(Salary), 85 | @Average = AVG(Salary), 86 | @Sum = SUM(Salary) 87 | FROM Employee; 88 | END 89 | GO 90 | 91 | /****** Object: StoredProcedure [dbo].[GetSalarySummary] Script Date: 12/28/2020 6:54:47 PM ******/ 92 | SET ANSI_NULLS ON 93 | GO 94 | 95 | SET QUOTED_IDENTIFIER ON 96 | GO 97 | -- ============================================= 98 | -- Author: Zaki Mohammed 99 | -- Create date: 7:46 PM 5/13/2020 100 | -- Description: Get salary summary 101 | -- ============================================= 102 | CREATE PROCEDURE [dbo].[GetSalarySummary] 103 | AS 104 | BEGIN 105 | -- get department wise salary summary 106 | SELECT 107 | Department, 108 | COUNT(1) EmployeeCount, 109 | SUM(Salary) AS Salary, 110 | SUM(Salary) * 12 AS Annual 111 | FROM 112 | Employee 113 | GROUP BY 114 | Department 115 | ORDER BY 116 | SUM(Salary) DESC; 117 | 118 | -- get job wise salary summary 119 | SELECT 120 | Job, 121 | COUNT(1) EmployeeCount, 122 | SUM(Salary) AS Salary, 123 | SUM(Salary) * 12 AS Annual 124 | FROM 125 | Employee 126 | GROUP BY 127 | Job 128 | ORDER BY 129 | SUM(Salary) DESC; 130 | END 131 | GO 132 | 133 | /****** Object: UserDefinedTableType [dbo].[EmployeeType] Script Date: 12/28/2020 6:55:46 PM ******/ 134 | CREATE TYPE [dbo].[EmployeeType] AS TABLE( 135 | [Code] [varchar](50) NOT NULL, 136 | [Name] [varchar](50) NULL, 137 | [Job] [varchar](50) NULL, 138 | [Salary] [int] NULL, 139 | [Department] [varchar](50) NULL 140 | ) 141 | GO 142 | 143 | /****** Object: StoredProcedure [dbo].[AddEmployees] Script Date: 12/28/2020 6:55:27 PM ******/ 144 | SET ANSI_NULLS ON 145 | GO 146 | 147 | SET QUOTED_IDENTIFIER ON 148 | GO 149 | 150 | -- ============================================= 151 | -- Author: Zaki Mohammed 152 | -- Create date: 1:18 AM 9/2/2020 153 | -- Description: Insert multiple-employees 154 | -- ============================================= 155 | CREATE PROCEDURE [dbo].[AddEmployees] 156 | @Employees EmployeeType READONLY 157 | AS 158 | BEGIN 159 | DECLARE @lastId INT; 160 | 161 | SET @lastId = (SELECT MAX(Id) AS LastId FROM Employee); 162 | 163 | INSERT INTO Employee (Code, [Name], Job, Salary, Department) 164 | SELECT * FROM @Employees; 165 | 166 | SELECT * FROM Employee WHERE Id > @lastId; 167 | END 168 | GO -------------------------------------------------------------------------------- /api/employees.js: -------------------------------------------------------------------------------- 1 | const express = require('express') 2 | const mssql = require('mssql') 3 | 4 | const router = express.Router(); 5 | 6 | const config = { 7 | driver: process.env.SQL_DRIVER, 8 | server: process.env.SQL_SERVER, 9 | database: process.env.SQL_DATABASE, 10 | user: process.env.SQL_UID, 11 | password: process.env.SQL_PWD, 12 | options: { 13 | encrypt: false, 14 | enableArithAbort: false 15 | }, 16 | }; 17 | const pool = new mssql.ConnectionPool(config); 18 | 19 | router.get('/search', async (req, res) => { 20 | try { 21 | await pool.connect(); 22 | const result = await pool.request() 23 | .input('Name', req.query.name) 24 | .execute(`SearchEmployee`); 25 | const employees = result.recordset; 26 | 27 | res.json(employees); 28 | } catch (error) { 29 | res.status(500).json(error); 30 | } 31 | }); 32 | router.get('/status', async (req, res) => { 33 | try { 34 | await pool.connect(); 35 | const result = await pool.request() 36 | .output('Count', 0) 37 | .output('Max', 0) 38 | .output('Min', 0) 39 | .output('Average', 0) 40 | .output('Sum', 0) 41 | .execute(`GetEmployeesStatus`); 42 | const status = { 43 | Count: +result.output.Count, 44 | Max: +result.output.Max, 45 | Min: +result.output.Min, 46 | Average: +result.output.Average, 47 | Sum: +result.output.Sum 48 | }; 49 | 50 | res.json(status); 51 | } catch (error) { 52 | res.status(500).json(error); 53 | } 54 | }); 55 | router.get('/summary', async (req, res) => { 56 | try { 57 | await pool.connect(); 58 | const result = await pool.request().execute(`GetSalarySummary`); 59 | const summary = { 60 | Department: result.recordsets[0], 61 | Job: result.recordsets[1], 62 | }; 63 | 64 | res.json(summary); 65 | } catch (error) { 66 | res.status(500).json(error); 67 | } 68 | }); 69 | router.post('/many', async (req, res) => { 70 | try { 71 | await pool.connect(); 72 | const employeesTable = new mssql.Table(); 73 | 74 | employeesTable.columns.add('Code', mssql.VarChar(50)); 75 | employeesTable.columns.add('Name', mssql.VarChar(50)); 76 | employeesTable.columns.add('Job', mssql.VarChar(50)); 77 | employeesTable.columns.add('Salary', mssql.Int); 78 | employeesTable.columns.add('Department', mssql.VarChar(50)); 79 | 80 | const employees = req.body; 81 | employees.forEach(employee => { 82 | employeesTable.rows.add( 83 | employee.Code, 84 | employee.Name, 85 | employee.Job, 86 | employee.Salary, 87 | employee.Department 88 | ) 89 | }); 90 | 91 | const request = pool.request(); 92 | request.input('Employees', employeesTable); 93 | 94 | const result = await request.execute('AddEmployees'); 95 | const newEmployees = result.recordset; 96 | res.json(newEmployees); 97 | } catch (error) { 98 | res.status(500).json(error); 99 | } 100 | }); 101 | 102 | router.get('/:id', async (req, res) => { 103 | try { 104 | await pool.connect(); 105 | const result = await pool.request() 106 | .input('Id', req.params.id) 107 | .query(`SELECT * FROM Employee WHERE Id = @Id`); 108 | const employee = result.recordset.length ? result.recordset[0] : null; 109 | 110 | if (employee) { 111 | res.json(employee); 112 | } else { 113 | res.status(404).json({ 114 | message: 'Record not found' 115 | }); 116 | } 117 | } catch (error) { 118 | res.status(500).json(error); 119 | } 120 | }); 121 | router.get('/', async (req, res) => { 122 | try { 123 | await pool.connect(); 124 | const result = await pool.request().query(`SELECT * FROM Employee ORDER BY Id DESC`); 125 | const employees = result.recordset; 126 | 127 | res.json(employees); 128 | } catch (error) { 129 | res.status(500).json(error); 130 | } 131 | }); 132 | router.post('/', async (req, res) => { 133 | try { 134 | await pool.connect(); 135 | const result = await pool.request() 136 | .input('Code', req.body.Code) 137 | .input('Salary', req.body.Salary) 138 | .input('Job', req.body.Job) 139 | .input('Department', req.body.Department) 140 | .input('Name', req.body.Name) 141 | .query(` 142 | INSERT INTO Employee (Code, Salary, Job, Department, Name) 143 | OUTPUT inserted.Id 144 | VALUES (@Code, @Salary, @Job, @Department, @Name); 145 | `); 146 | const employee = req.body; 147 | employee.Id = result.recordset[0].Id; 148 | res.json(employee); 149 | } catch (error) { 150 | res.status(500).json(error); 151 | } 152 | }); 153 | router.put('/:id', async (req, res) => { 154 | try { 155 | if (+req.params.id !== req.body.Id) { 156 | res.status(400).json({ 157 | message: 'Mismatched identity' 158 | }); 159 | return; 160 | } 161 | 162 | await pool.connect(); 163 | const result = await pool.request() 164 | .input('Id', req.params.id) 165 | .query(`SELECT * FROM Employee WHERE Id = @Id`); 166 | 167 | let employee = result.recordset.length ? result.recordset[0] : null; 168 | if (employee) { 169 | await pool.request() 170 | .input('Id', req.params.id) 171 | .input('Code', req.body.Code) 172 | .input('Salary', req.body.Salary) 173 | .input('Job', req.body.Job) 174 | .input('Department', req.body.Department) 175 | .input('Name', req.body.Name) 176 | .query(` 177 | UPDATE Employee SET 178 | Code = @Code, 179 | Salary = @Salary, 180 | Job = @Job, 181 | Department = @Department, 182 | Name = @Name 183 | WHERE Id = @Id; 184 | `); 185 | 186 | employee = { ...employee, ...req.body }; 187 | 188 | res.json(employee); 189 | } else { 190 | res.status(404).json({ 191 | message: 'Record not found' 192 | }); 193 | } 194 | } catch (error) { 195 | res.status(500).json(error); 196 | } 197 | }); 198 | router.delete('/:id', async (req, res) => { 199 | try { 200 | await pool.connect(); 201 | const result = await pool.request() 202 | .input('Id', req.params.id) 203 | .query(`SELECT * FROM Employee WHERE Id = @Id`); 204 | 205 | let employee = result.recordset.length ? result.recordset[0] : null; 206 | if (employee) { 207 | await pool.request() 208 | .input('Id', req.params.id) 209 | .query(`DELETE FROM Employee WHERE Id = @Id;`); 210 | res.json(employee); 211 | } else { 212 | res.status(404).json({ 213 | message: 'Record not found' 214 | }); 215 | } 216 | } catch (error) { 217 | res.status(500).json(error); 218 | } 219 | }); 220 | 221 | module.exports = router; --------------------------------------------------------------------------------