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

Fetch table columns & triggers #14

Merged
merged 9 commits into from
Apr 19, 2016
6 changes: 6 additions & 0 deletions spec/databases/mysql/schema/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -23,3 +23,9 @@ BEGIN
SELECT COUNT(*) FROM users;
END$$
DELIMITER ;

DROP TRIGGER IF EXISTS dummy_trigger;
CREATE TRIGGER dummy_trigger AFTER INSERT ON users
FOR EACH ROW
BEGIN
END;
11 changes: 11 additions & 0 deletions spec/databases/postgresql/schema/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -18,3 +18,14 @@ CREATE OR REPLACE FUNCTION user_count()
RETURNS bigint AS $$
SELECT COUNT(*) FROM users AS total;
$$ LANGUAGE SQL;

DROP TRIGGER IF EXISTS dummy_trigger ON users;
CREATE OR REPLACE FUNCTION test_trigger_func() RETURNS TRIGGER AS $$
BEGIN
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER dummy_trigger
AFTER INSERT ON users
FOR EACH ROW
EXECUTE PROCEDURE test_trigger_func();
13 changes: 13 additions & 0 deletions spec/databases/sqlserver/schema/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -35,3 +35,16 @@ AS
BEGIN
SELECT @Count = COUNT(*) FROM dbo.users
END
GO

IF EXISTS (SELECT * FROM sys.objects WHERE [type] = 'TR' AND [name] = 'dummy_trigger')
DROP TRIGGER dbo.dummy_trigger;
GO

CREATE TRIGGER dbo.dummy_trigger
ON users
AFTER INSERT
AS
BEGIN
return
END
40 changes: 39 additions & 1 deletion spec/db.spec.js
Original file line number Diff line number Diff line change
Expand Up @@ -94,18 +94,56 @@ describe('db', () => {
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
// Futhermore, PostgreSQL is expected to have two functions in schema, because
// additional one is needed for trigger
if (dbClient === 'postgresql') {
expect(routines).to.have.length(2);
expect(routine).to.have.deep.property('routineType').to.eql('FUNCTION');
} else {
expect(routines).to.have.length(1);
expect(routine).to.have.deep.property('routineType').to.eql('PROCEDURE');
}
});
});

describe('.listTableColumns', () => {
it('should list all columns and their type from users table', async() => {
const columns = await dbConn.listTableColumns('users');
expect(columns).to.have.length(4);
const [firstCol, secondCol, thirdCol, fourthCol ] = columns;

expect(firstCol).to.have.property('columnName').to.eql('id');
expect(secondCol).to.have.property('columnName').to.eql('username');
expect(thirdCol).to.have.property('columnName').to.eql('email');
expect(fourthCol).to.have.property('columnName').to.eql('password');

expect(firstCol).to.have.property('dataType').to.have.string('int');

// According to schemas defined in specs, Postgresql has last three column
// types set as text, while in mysql and mssql they are defined as varchar
if (dbClient === 'postgresql') {
expect(secondCol).to.have.property('dataType').to.eql('text');
expect(thirdCol).to.have.property('dataType').to.eql('text');
expect(fourthCol).to.have.property('dataType').to.eql('text');
} else {
expect(secondCol).to.have.property('dataType').to.eql('varchar');
expect(thirdCol).to.have.property('dataType').to.eql('varchar');
expect(fourthCol).to.have.property('dataType').to.eql('varchar');
}
});
});

describe('.listTableTriggers', () => {
it('should list all table related triggers', async() => {
const triggers = await dbConn.listTableTriggers('users');
expect(triggers).to.have.length(1);
expect(triggers).to.include.members(['dummy_trigger']);
});
});

describe('.executeQuery', () => {
beforeEach(() => Promise.all([
dbConn.executeQuery(`
Expand Down
12 changes: 12 additions & 0 deletions src/db/client.js
Original file line number Diff line number Diff line change
Expand Up @@ -20,6 +20,8 @@ export function createConnection(server, database) {
listTables: listTables.bind(null, server, database),
listViews: listViews.bind(null, server, database),
listRoutines: listRoutines.bind(null, server, database),
listTableColumns: listTableColumns.bind(null, server, database),
listTableTriggers: listTableTriggers.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 @@ -119,6 +121,16 @@ async function listRoutines(server, database) {
return database.connection.listRoutines();
}

async function listTableColumns(server, database, table) {
Copy link
Member

Choose a reason for hiding this comment

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

it does not need async

Copy link
Member

Choose a reason for hiding this comment

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

I guess need the async because of the https://github.com/BornaP/sqlectron-core/blob/13-fetch-table-columns/src/db/client.js#L172.
That throws an exception. I guess without the async it will not reject the promise properly.
Since that is the current pattern used for all functions in that file. I will accept without applying your suggestions. We can try out without async in another commit.

checkIsConnected(server, database);
return database.connection.listTableColumns(table);
}

async function listTableTriggers(server, database, table) {
Copy link
Member

Choose a reason for hiding this comment

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

it does not need async

checkIsConnected(server, database);
return database.connection.listTableTriggers(table);
}

async function executeQuery(server, database, query) {
Copy link
Member

Choose a reason for hiding this comment

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

it does not need async

checkIsConnected(server, database);
return database.connection.executeQuery(query);
Expand Down
41 changes: 41 additions & 0 deletions src/db/clients/mysql.js
Original file line number Diff line number Diff line change
Expand Up @@ -31,6 +31,8 @@ export default function(server, database) {
listTables: () => listTables(client),
listViews: () => listViews(client),
listRoutines: () => listRoutines(client),
listTableColumns: (table) => listTableColumns(client, table),
listTableTriggers: (table) => listTableTriggers(client, table),
executeQuery: (query) => executeQuery(client, query),
listDatabases: () => listDatabases(client),
getQuerySelectTop: (table, limit) => getQuerySelectTop(client, table, limit),
Expand Down Expand Up @@ -98,6 +100,45 @@ export function listRoutines(client) {
});
}

export function listTableColumns(client, table) {
return new Promise((resolve, reject) => {
const sql = `
SELECT column_name, data_type
FROM information_schema.columns
WHERE table_schema = database()
AND table_name = ?
`;
const params = [
table,
];
client.query(sql, params, (err, data) => {
if (err) return reject(_getRealError(client, err));
resolve(data.map(row => ({
columnName: row.column_name,
dataType: row.data_type,
})));
});
});
}

export function listTableTriggers(client, table) {
return new Promise((resolve, reject) => {
const sql = `
SELECT trigger_name
FROM information_schema.triggers
WHERE event_object_schema = database()
AND event_object_table = ?
`;
const params = [
table,
];
client.query(sql, params, (err, data) => {
if (err) return reject(_getRealError(client, err));
resolve(data.map(row => row.trigger_name));
});
});
}

export function executeQuery(client, query) {
return new Promise((resolve, reject) => {
client.query(query, (err, data, fields) => {
Expand Down
43 changes: 43 additions & 0 deletions src/db/clients/postgresql.js
Original file line number Diff line number Diff line change
Expand Up @@ -25,6 +25,8 @@ export default function(server, database) {
listTables: () => listTables(client),
listViews: () => listViews(client),
listRoutines: () => listRoutines(client),
listTableColumns: (table) => listTableColumns(client, table),
listTableTriggers: (table) => listTableTriggers(client, table),
executeQuery: (query) => executeQuery(client, query),
listDatabases: () => listDatabases(client),
getQuerySelectTop: (table, limit) => getQuerySelectTop(client, table, limit),
Expand Down Expand Up @@ -98,6 +100,47 @@ export function listRoutines(client) {
});
}

export function listTableColumns(client, table) {
return new Promise((resolve, reject) => {
const sql = `
SELECT column_name, data_type
FROM information_schema.columns
WHERE table_schema = $1
AND table_name = $2
`;
const params = [
'public',
table,
];
client.query(sql, params, (err, data) => {
if (err) return reject(err);
resolve(data.rows.map(row => ({
columnName: row.column_name,
dataType: row.data_type,
})));
});
});
}

export function listTableTriggers(client, table) {
return new Promise((resolve, reject) => {
const sql = `
SELECT trigger_name
FROM information_schema.triggers
WHERE event_object_schema = $1
AND event_object_table = $2
`;
const params = [
'public',
table,
];
client.query(sql, params, (err, data) => {
if (err) return reject(err);
resolve(data.rows.map(row => row.trigger_name));
});
});
}

export async function executeQuery(client, query) {
// node-postgres has support for Promise query
// but that always returns the "fields" property empty
Expand Down
25 changes: 25 additions & 0 deletions src/db/clients/sqlserver.js
Original file line number Diff line number Diff line change
Expand Up @@ -21,6 +21,8 @@ export default async function(server, database) {
listTables: () => listTables(connection),
listViews: () => listViews(connection),
listRoutines: () => listRoutines(connection),
listTableColumns: (table) => listTableColumns(connection, table),
listTableTriggers: (table) => listTableTriggers(connection, table),
executeQuery: (query) => executeQuery(connection, query),
listDatabases: () => listDatabases(connection),
getQuerySelectTop: (table, limit) => getQuerySelectTop(connection, table, limit),
Expand Down Expand Up @@ -94,6 +96,29 @@ export const listRoutines = async (connection) => {
}));
};

export const listTableColumns = async (connection, table) => {
const sql = `
SELECT column_name, data_type
FROM information_schema.columns
WHERE table_name = '${table}'
`;
const [result] = await executeQuery(connection, sql);
return result.rows.map(row => ({
columnName: row.column_name,
dataType: row.data_type,
}));
};

export const listTableTriggers = async (connection, table) => {
// SQL Server does not have information_schema for triggers, so other way around
// is using sp_helptrigger stored procedure to fetch triggers related to table
const sql = `
EXEC sp_helptrigger ${wrapQuery(table)}
`;
const [result] = await executeQuery(connection, sql);
return result.rows.map(row => row.trigger_name);
};

export const listDatabases = async (connection) => {
const [result] = await executeQuery(connection, 'SELECT name FROM sys.databases');
return result.rows.map(row => row.name);
Expand Down