diff --git a/spec/databases/mysql/schema/schema.sql b/spec/databases/mysql/schema/schema.sql index f01c28b..d91b0f9 100644 --- a/spec/databases/mysql/schema/schema.sql +++ b/spec/databases/mysql/schema/schema.sql @@ -12,3 +12,14 @@ CREATE TABLE IF NOT EXISTS `roles` ( `name` VARCHAR(100) NULL, PRIMARY KEY (`id`)) ENGINE = InnoDB; + +CREATE OR REPLACE VIEW `email_view` AS + SELECT users.email, users.password + FROM users; + +DELIMITER $$ +CREATE PROCEDURE `users_count`() +BEGIN + SELECT COUNT(*) FROM users; +END$$ +DELIMITER ; diff --git a/spec/databases/postgresql/schema/schema.sql b/spec/databases/postgresql/schema/schema.sql index a0e7b69..6b0487d 100644 --- a/spec/databases/postgresql/schema/schema.sql +++ b/spec/databases/postgresql/schema/schema.sql @@ -9,3 +9,12 @@ CREATE TABLE roles( id SERIAL PRIMARY KEY, name TEXT NOT NULL ); + +CREATE OR REPLACE VIEW email_view AS + SELECT users.email, users.password + FROM users; + +CREATE OR REPLACE FUNCTION user_count() +RETURNS bigint AS $$ + SELECT COUNT(*) FROM users AS total; +$$ LANGUAGE SQL; diff --git a/spec/databases/sqlserver/schema/schema.sql b/spec/databases/sqlserver/schema/schema.sql index dc0b55c..e1cc458 100644 --- a/spec/databases/sqlserver/schema/schema.sql +++ b/spec/databases/sqlserver/schema/schema.sql @@ -5,11 +5,33 @@ CREATE TABLE dbo.users username varchar(45) NULL, email varchar(150) NULL, password varchar(45) NULL) -END +END; IF NOT EXISTS (SELECT * FROM sys.tables WHERE name = N'roles' AND type = 'U') BEGIN CREATE TABLE dbo.roles (id int PRIMARY KEY IDENTITY(1,1) NOT NULL, name varchar(100) NULL) -END +END; + +IF EXISTS (SELECT table_name FROM information_schema.views WHERE table_name = 'email_view') + DROP VIEW dbo.email_view +GO + +CREATE VIEW dbo.email_view AS +SELECT dbo.users.email, dbo.users.password +FROM dbo.users; +GO + +IF OBJECT_ID('dbo.users_count', 'P') IS NOT NULL + DROP PROCEDURE dbo.users_count +GO + +CREATE PROCEDURE dbo.users_count +( + @Count int OUTPUT +) +AS + BEGIN + SELECT @Count = COUNT(*) FROM dbo.users + END diff --git a/spec/db.spec.js b/spec/db.spec.js index 8bbd33d..a22f5fc 100644 --- a/spec/db.spec.js +++ b/spec/db.spec.js @@ -70,6 +70,28 @@ describe('db', () => { }); }); + describe('.listViews', () => { + it('should list all views', async () => { + const views = await dbConn.listViews(); + expect(views).to.include.members(['email_view']); + }); + }); + + describe('.listRoutines', () => { + it('should list all routines and their type', async() =>{ + const routines = await dbConn.listRoutines(); + expect(routines).to.have.length(1); + const [routine] = routines; + + // Postgresql routine type is always function. SP do not exist + if (dbClient === 'postgresql') { + expect(routine).to.have.deep.property('routineType').to.eql('FUNCTION'); + } else { + expect(routine).to.have.deep.property('routineType').to.eql('PROCEDURE'); + } + }); + }); + describe('.executeQuery', () => { beforeEach(() => Promise.all([ dbConn.executeQuery(` diff --git a/src/db/client.js b/src/db/client.js index d560c0d..6838794 100644 --- a/src/db/client.js +++ b/src/db/client.js @@ -18,6 +18,8 @@ export function createConnection(server, database) { connect: connect.bind(null, server, database), disconnect: disconnect.bind(null, server, database), listTables: listTables.bind(null, server, database), + listViews: listViews.bind(null, server, database), + listRoutines: listRoutines.bind(null, server, database), executeQuery: executeQuery.bind(null, server, database), listDatabases: listDatabases.bind(null, server, database), getQuerySelectTop: getQuerySelectTop.bind(null, server, database), @@ -107,6 +109,15 @@ async function listTables(server, database) { return database.connection.listTables(); } +async function listViews(server, database) { + checkIsConnected(server, database); + return database.connection.listViews(); +} + +async function listRoutines(server, database) { + checkIsConnected(server, database); + return database.connection.listRoutines(); +} async function executeQuery(server, database, query) { checkIsConnected(server, database); diff --git a/src/db/clients/mysql.js b/src/db/clients/mysql.js index 1674bc1..9c5c156 100644 --- a/src/db/clients/mysql.js +++ b/src/db/clients/mysql.js @@ -29,6 +29,8 @@ export default function(server, database) { resolve({ disconnect: () => disconnect(client), listTables: () => listTables(client), + listViews: () => listViews(client), + listRoutines: () => listRoutines(client), executeQuery: (query) => executeQuery(client, query), listDatabases: () => listDatabases(client), getQuerySelectTop: (table, limit) => getQuerySelectTop(client, table, limit), @@ -50,6 +52,7 @@ export function listTables(client) { SELECT table_name FROM information_schema.tables WHERE table_schema = database() + AND table_type NOT LIKE '%VIEW%' ORDER BY table_name `; const params = []; @@ -60,6 +63,40 @@ export function listTables(client) { }); } +export function listViews(client) { + return new Promise((resolve, reject) => { + const sql = ` + SELECT table_name + FROM information_schema.views + WHERE table_schema = database() + ORDER BY table_name + `; + const params = []; + client.query(sql, params, (err, data) => { + if (err) return reject(_getRealError(client, err)); + resolve(data.map(row => row.table_name)); + }); + }); +} + +export function listRoutines(client) { + return new Promise((resolve, reject) => { + const sql = ` + SELECT routine_name, routine_type + FROM information_schema.routines + WHERE routine_schema = database() + ORDER BY routine_name + `; + const params = []; + client.query(sql, params, (err, data) => { + if (err) return reject(_getRealError(client, err)); + resolve(data.map(row => ({ + routineName: row.routine_name, + routineType: row.routine_type, + }))); + }); + }); +} export function executeQuery(client, query) { return new Promise((resolve, reject) => { @@ -110,6 +147,7 @@ export const truncateAllTables = async (client) => { SELECT table_name FROM information_schema.tables WHERE table_schema = '${schema}' + AND table_type NOT LIKE '%VIEW%' `; const [result] = await executeQuery(client, sql); const tables = result.rows.map(row => row.table_name); diff --git a/src/db/clients/postgresql.js b/src/db/clients/postgresql.js index cbf8eb7..81ce828 100644 --- a/src/db/clients/postgresql.js +++ b/src/db/clients/postgresql.js @@ -23,6 +23,8 @@ export default function(server, database) { wrapQuery, disconnect: () => disconnect(client), listTables: () => listTables(client), + listViews: () => listViews(client), + listRoutines: () => listRoutines(client), executeQuery: (query) => executeQuery(client, query), listDatabases: () => listDatabases(client), getQuerySelectTop: (table, limit) => getQuerySelectTop(client, table, limit), @@ -44,6 +46,7 @@ export function listTables(client) { SELECT table_name FROM information_schema.tables WHERE table_schema = $1 + AND table_type NOT LIKE '%VIEW%' ORDER BY table_name `; const params = [ @@ -56,6 +59,44 @@ export function listTables(client) { }); } +export function listViews(client) { + return new Promise((resolve, reject) => { + const sql = ` + SELECT table_name + FROM information_schema.views + WHERE table_schema = $1 + ORDER BY table_name + `; + const params = [ + 'public', + ]; + client.query(sql, params, (err, data) => { + if (err) return reject(err); + resolve(data.rows.map(row => row.table_name)); + }); + }); +} + +export function listRoutines(client) { + return new Promise((resolve, reject) => { + const sql = ` + SELECT routine_name, routine_type + FROM information_schema.routines + WHERE routine_schema = $1 + ORDER BY routine_name + `; + const params = [ + 'public', + ]; + client.query(sql, params, (err, data) => { + if (err) return reject(err); + resolve(data.rows.map(row => ({ + routineName: row.routine_name, + routineType: row.routine_type, + }))); + }); + }); +} export async function executeQuery(client, query) { // node-postgres has support for Promise query @@ -107,6 +148,7 @@ export const truncateAllTables = async (connection) => { SELECT table_name FROM information_schema.tables WHERE table_schema = '${schema}' + AND table_type NOT LIKE '%VIEW%' `; const [result] = await executeQuery(connection, sql); const tables = result.rows.map(row => row.table_name); diff --git a/src/db/clients/sqlserver.js b/src/db/clients/sqlserver.js index 2ea6d6c..ea53ceb 100644 --- a/src/db/clients/sqlserver.js +++ b/src/db/clients/sqlserver.js @@ -19,6 +19,8 @@ export default async function(server, database) { return { disconnect: () => disconnect(connection), listTables: () => listTables(connection), + listViews: () => listViews(connection), + listRoutines: () => listRoutines(connection), executeQuery: (query) => executeQuery(connection, query), listDatabases: () => listDatabases(connection), getQuerySelectTop: (table, limit) => getQuerySelectTop(connection, table, limit), @@ -62,12 +64,35 @@ export const listTables = async (connection) => { const sql = ` SELECT table_name FROM information_schema.tables + WHERE table_type NOT LIKE '%VIEW%' ORDER BY table_name `; const [result] = await executeQuery(connection, sql); return result.rows.map(row => row.table_name); }; +export const listViews = async (connection) => { + const sql = ` + SELECT table_name + FROM information_schema.views + ORDER BY table_name + `; + const [result] = await executeQuery(connection, sql); + return result.rows.map(row => row.table_name); +}; + +export const listRoutines = async (connection) => { + const sql = ` + SELECT routine_name, routine_type + FROM information_schema.routines + ORDER BY routine_name + `; + const [result] = await executeQuery(connection, sql); + return result.rows.map(row => ({ + routineName: row.routine_name, + routineType: row.routine_type, + })); +}; export const listDatabases = async (connection) => { const [result] = await executeQuery(connection, 'SELECT name FROM sys.databases'); @@ -81,6 +106,7 @@ export const truncateAllTables = async (connection) => { SELECT table_name FROM information_schema.tables WHERE table_schema = '${schema}' + AND table_type NOT LIKE '%VIEW%' `; const [result] = await executeQuery(connection, sql); const tables = result.rows.map(row => row.table_name);