Skip to content
This repository has been archived by the owner on Mar 15, 2021. It is now read-only.

Database metadata #10

Merged
merged 7 commits into from
Mar 25, 2016
Merged
Show file tree
Hide file tree
Changes from 2 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
11 changes: 11 additions & 0 deletions spec/databases/mysql/schema/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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 ;
9 changes: 9 additions & 0 deletions spec/databases/postgresql/schema/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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;
22 changes: 22 additions & 0 deletions spec/db.spec.js
Original file line number Diff line number Diff line change
Expand Up @@ -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(`
Expand Down
11 changes: 11 additions & 0 deletions src/db/client.js
Original file line number Diff line number Diff line change
Expand Up @@ -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),
Expand Down Expand Up @@ -107,6 +109,15 @@ async function listTables(server, database) {
return database.connection.listTables();
}

async function listViews(server, database) {
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

as does not have usage of await inside block it does not need to have async

checkIsConnected(server, database);
return database.connection.listViews();
}

async function listRoutines(server, database) {
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

same as above

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

You're right. Also I guess, async should be omitted in similar cases with listTables and listDatabases functions?

checkIsConnected(server, database);
return database.connection.listRoutines();
}

async function executeQuery(server, database, query) {
checkIsConnected(server, database);
Expand Down
37 changes: 37 additions & 0 deletions src/db/clients/mysql.js
Original file line number Diff line number Diff line change
Expand Up @@ -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),
Expand Down Expand Up @@ -60,6 +62,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) => {
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

as params is not used anywhere else, perhaps you can pass directly one []...

 client.query(sql, [], (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) => {
Expand Down Expand Up @@ -110,6 +146,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);
Expand Down
41 changes: 41 additions & 0 deletions src/db/clients/postgresql.js
Original file line number Diff line number Diff line change
Expand Up @@ -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),
Expand Down Expand Up @@ -56,6 +58,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) => {
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

same as above perhaps can pass directly ['public'] ...

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
Expand Down Expand Up @@ -107,6 +147,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);
Expand Down