diff --git a/db/.gitignore b/db/.gitignore new file mode 100644 index 0000000000000000000000000000000000000000..40bc57be252f5cfd19a9fad5a7fc841f65f25dc2 --- /dev/null +++ b/db/.gitignore @@ -0,0 +1,9 @@ +node_modules/ +config.js +config_test.js +logs/ +*.swp +nohup.out +package-lock.json +coverage/ +.nyc_output/ diff --git a/db/README.md b/db/README.md new file mode 100644 index 0000000000000000000000000000000000000000..23812a1741ad507daebdd4b735615c728142f0ac --- /dev/null +++ b/db/README.md @@ -0,0 +1,44 @@ +# Create/Migrate DB PInSIS + +Módulo para criar/migrar as relações do banco de dados do projeto PInSIS + +Este projeto utiliza o [node-pg-migrate](https://github.com/salsita/node-pg-migrate). + + +## Exemplo de uso: + +```bash +DATABASE_URL='postgresql://logindb:password@localhost/dbtest' npm run migrate up # Cria todos os schemas +DATABASE_URL='postgresql://logindb:password@localhost/dbtest' npm run migrate down # Cria o banco de dados +``` + +Observe que é necessário definir uma variável de ambiente ao executar os comandos acima. +Para uma documentação mais completa e métodos alternativos de utilizar os comandos consule [node-pg-migrate CLI Usage](https://github.com/salsita/node-pg-migrate/blob/master/docs/cli.md) + +## Camadas + +Observe que quando os migrates ups executados no exemplo anterior passarão por todas as migrações existentes em ./migrations e criarão os modelos na ordem cronológica. +No caso dos migrates downs, cada execução irá "descer uma camada" em relação à s migrações. + +Consulte a documentação original para ver métodos alternativos para simplificar o uso. + +## Migrar o banco + +```bash +# Esses comandos criarão modelos no diretório /migrations + +# Por questões de padronização, adotou-se que os nomes das migrações +# teriam espacamento substituido por _ +# por exemplo: add_table_1 +# alter_colum_x_from_table2 + +npm run migrate create nome da migracao +npm run migrate create migration4 +npm run migrate create migration5 +``` + +## PossÃveis erros + +- Os principais problemas encontrados estão relacionados à conexão com o DB + Em caso de erros verifique se é possÃvel fazer conexão com o DB com o + psql por exemplo (no mesmo usuário em que está se executando os comandos) diff --git a/db/migrations/1524235595755_add_table_agent.js b/db/migrations/1524235595755_add_table_agent.js new file mode 100644 index 0000000000000000000000000000000000000000..2f83d879d43192e2864914a5465b136d93119a94 --- /dev/null +++ b/db/migrations/1524235595755_add_table_agent.js @@ -0,0 +1,42 @@ +/* + * Copyright (C) 2018 Centro de Computacao Cientifica e Software Livre + * Departamento de Informatica - Universidade Federal do Parana - C3SL/UFPR + * + * This file is part of pinsis + * + * pinsis is free software; you can redistribute it and/or + * modify it under the terms of the GNU General Public License + * as published by the Free Software Foundation; either version 2 + * of the License, or (at your option) any later version. + * + * This program is distributed in the hope that it will be useful, + * but WITHOUT ANY WARRANTY; without even the implied warranty of + * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + * GNU General Public License for more details. + * + * You should have received a copy of the GNU General Public License + * along with this program; if not, write to the Free Software + * Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, + * USA. +*/ + +exports.shorthands = undefined; + +exports.up = (pgm) => { + + // Agent information + pgm.createTable("agent", { + id: {type: "BIGSERIAL", primaryKey: true}, + hospital_name: { type: "VARCHAR(16)", notNull: true }, + geo_long: { type: "FLOAT", notNull: true }, + geo_lat: { type: "FLOAT", notNull: true }, + countie: { type: "VARCHAR(64)", notNull: true }, + state: { type: "VARCHAR(64)", notNull: true }, + region: { type: "VARCHAR(64)", notNull: true }, + }); +}; + +exports.down = (pgm) => { + // Drop all created tables in this migrate + pgm.dropTable( "agent"); +}; diff --git a/db/migrations/1524235653823_add_table_machineuse.js b/db/migrations/1524235653823_add_table_machineuse.js new file mode 100644 index 0000000000000000000000000000000000000000..154ab179b973a4bd6b761b14bf2c839d20ef6bd4 --- /dev/null +++ b/db/migrations/1524235653823_add_table_machineuse.js @@ -0,0 +1,47 @@ +/* + * Copyright (C) 2018 Centro de Computacao Cientifica e Software Livre + * Departamento de Informatica - Universidade Federal do Parana - C3SL/UFPR + * + * This file is part of pinsis + * + * pinsis is free software; you can redistribute it and/or + * modify it under the terms of the GNU General Public License + * as published by the Free Software Foundation; either version 2 + * of the License, or (at your option) any later version. + * + * This program is distributed in the hope that it will be useful, + * but WITHOUT ANY WARRANTY; without even the implied warranty of + * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + * GNU General Public License for more details. + * + * You should have received a copy of the GNU General Public License + * along with this program; if not, write to the Free Software + * Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, + * USA. +*/ + +exports.shorthands = undefined; + +exports.up = (pgm) => { + + // Same relation of the view in Oracle Database + // This will be populated with TASY json data + pgm.createTable("machineuse", { + id: {type: "BIGSERIAL", primaryKey: true}, + nr_prontuario: { type: "BIGINT", notNull: true }, + convenio: { type: "VARCHAR(64)", notNull: true }, + status: { type: "VARCHAR(64)", notNull: true }, + nr_cartao_nac_sus: { type: "BIGINT", notNull: true }, + dt_agenda: { type: "TIMESTAMP", notNull: true }, + fk_agent: { type: "INT", notNull: true, references:"agent"}, + }); + + + // Rule to avoid duplicate data in DB + pgm.sql("ALTER TABLE machineuse ADD CONSTRAINT uc_use UNIQUE (dt_agenda, nr_cartao_nac_sus, convenio, nr_prontuario);"); +}; + +exports.down = (pgm) => { + // Drop all created tables in this migrate + pgm.dropTable( "machineuse"); +}; diff --git a/db/migrations/1524235757350_add_views_agentuses.js b/db/migrations/1524235757350_add_views_agentuses.js new file mode 100644 index 0000000000000000000000000000000000000000..928ae6dfc929c5ab0843f3a41fd26b11e4279380 --- /dev/null +++ b/db/migrations/1524235757350_add_views_agentuses.js @@ -0,0 +1,102 @@ +/* + * Copyright (C) 2018 Centro de Computacao Cientifica e Software Livre + * Departamento de Informatica - Universidade Federal do Parana - C3SL/UFPR + * + * This file is part of pinsis + * + * pinsis is free software; you can redistribute it and/or + * modify it under the terms of the GNU General Public License + * as published by the Free Software Foundation; either version 2 + * of the License, or (at your option) any later version. + * + * This program is distributed in the hope that it will be useful, + * but WITHOUT ANY WARRANTY; without even the implied warranty of + * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + * GNU General Public License for more details. + * + * You should have received a copy of the GNU General Public License + * along with this program; if not, write to the Free Software + * Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, + * USA. +*/ + +exports.shorthands = undefined; + +exports.up = (pgm) => { + + + // Auxiliar table + // This will be used to create cartesian products in relations operations + pgm.createTable("true_false_table", { + is_sus: { type: "BOOLEAN" }, + }); + pgm.sql( "insert into true_false_table values(true),(false);" ); + /////////////////// + + + // The follow views will resume the number of uses in all agents + // The views are separated in groups of year, month and day + // separated in uses of sus or not + + + // The big WITH clause is used to create 0 entries in results + // This is solve using cartesian product + + pgm.createMaterializedView( "agentusesyear", {}, + "WITH\ + trunc as (SELECT date_trunc('year', DT_AGENDA) AS date, CAST(count(*) AS INT) as uses, fk_agent, CASE WHEN CONVENIO = 'SUS' THEN true ELSE false END AS is_sus\ + FROM machineuse\ + GROUP BY date, fk_agent, is_sus\ + ORDER BY date),\ + range_dates as (SELECT DATE_TRUNC ('year', GENERATE_SERIES (MIN(DT_AGENDA), MAX(DT_AGENDA), '1 year'))::timestamp AS date FROM machineuse as m1),\ + range_fks as (SELECT DISTINCT fk_agent FROM machineuse),\ + markers as (SELECT * FROM true_false_table,range_fks,range_dates),\ + null_rows as (SELECT *, '0'::int as uses FROM markers),\ + res as (SELECT date,uses,fk_agent,is_sus FROM trunc UNION SELECT date,uses,fk_agent,is_sus FROM null_rows)\ + SELECT date,MAX(uses) as uses, fk_agent,is_sus from res\ + GROUP BY date,fk_agent,is_sus\ + ORDER BY date;" + ); + + pgm.createMaterializedView( "agentusesmonth", {}, + "WITH\ + trunc as (SELECT date_trunc('month', DT_AGENDA) AS date, CAST(count(*) AS INT) as uses, fk_agent, CASE WHEN CONVENIO = 'SUS' THEN true ELSE false END AS is_sus\ + FROM machineuse\ + GROUP BY date, fk_agent, is_sus\ + ORDER BY date),\ + range_dates as (SELECT DATE_TRUNC ('month', GENERATE_SERIES (MIN(DT_AGENDA), MAX(DT_AGENDA), '1 month'))::timestamp AS date FROM machineuse as m1),\ + range_fks as (SELECT DISTINCT fk_agent FROM machineuse),\ + markers as (SELECT * FROM true_false_table,range_fks,range_dates),\ + null_rows as (SELECT *, '0'::int as uses FROM markers),\ + res as (SELECT date,uses,fk_agent,is_sus FROM trunc UNION SELECT date,uses,fk_agent,is_sus FROM null_rows)\ + SELECT date,MAX(uses) as uses, fk_agent,is_sus from res\ + GROUP BY date,fk_agent,is_sus\ + ORDER BY date;" + ); + + pgm.createMaterializedView( "agentusesday", {}, + "WITH\ + trunc as (SELECT date_trunc('day', DT_AGENDA) AS date, CAST(count(*) AS INT) as uses, fk_agent, CASE WHEN CONVENIO = 'SUS' THEN true ELSE false END AS is_sus\ + FROM machineuse\ + GROUP BY date, fk_agent, is_sus\ + ORDER BY date),\ + range_dates as (SELECT DATE_TRUNC ('day', GENERATE_SERIES (MIN(DT_AGENDA), MAX(DT_AGENDA), '1 day'))::timestamp AS date FROM machineuse as m1),\ + range_fks as (SELECT DISTINCT fk_agent FROM machineuse),\ + markers as (SELECT * FROM true_false_table,range_fks,range_dates),\ + null_rows as (SELECT *, '0'::int as uses FROM markers),\ + res as (SELECT date,uses,fk_agent,is_sus FROM trunc UNION SELECT date,uses,fk_agent,is_sus FROM null_rows)\ + SELECT date,MAX(uses) as uses, fk_agent,is_sus from res\ + GROUP BY date,fk_agent,is_sus\ + ORDER BY date;" + ); + + +}; + +exports.down = (pgm) => { + // Drop all created tables in this migrate + pgm.dropMaterializedView( "agentusesyear", {} ); + pgm.dropMaterializedView( "agentusesmonth", {} ); + pgm.dropMaterializedView( "agentusesday", {} ); + pgm.dropTable( "true_false_table"); +}; diff --git a/db/migrations/1524235869466_add_views_agentusesbystatus.js b/db/migrations/1524235869466_add_views_agentusesbystatus.js new file mode 100644 index 0000000000000000000000000000000000000000..d849f9a5af460c1c4b4e5bd54671357107ac3b5c --- /dev/null +++ b/db/migrations/1524235869466_add_views_agentusesbystatus.js @@ -0,0 +1,108 @@ +/* + * Copyright (C) 2018 Centro de Computacao Cientifica e Software Livre + * Departamento de Informatica - Universidade Federal do Parana - C3SL/UFPR + * + * This file is part of pinsis + * + * pinsis is free software; you can redistribute it and/or + * modify it under the terms of the GNU General Public License + * as published by the Free Software Foundation; either version 2 + * of the License, or (at your option) any later version. + * + * This program is distributed in the hope that it will be useful, + * but WITHOUT ANY WARRANTY; without even the implied warranty of + * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + * GNU General Public License for more details. + * + * You should have received a copy of the GNU General Public License + * along with this program; if not, write to the Free Software + * Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, + * USA. +*/ + +exports.shorthands = undefined; + +exports.up = (pgm) => { + + // Auxiliar table + // This will be used to create cartesian products in relations operations + + // Values that is considered as executed status + pgm.createTable("executed_status", { + status: { type: "VARCHAR(64)" }, + }); + pgm.sql( "insert into executed_status values('Normal'),('Executada'),('Atendido'), ('Em Consulta'), ('Reservada');" ); + /////////////////// + + + + // The follow views will resume the number of uses in all agents + // where the status is considered as executed. + // The views are separated in groups of year, month and day + // separated in uses of sus or not + + + // The big WITH clause is used to create 0 entries in results + // This is solve using cartesian product + + pgm.createMaterializedView( "agentusesyearbystatus", {}, + "WITH\ + trunc as (SELECT date_trunc('year', DT_AGENDA) AS date, CAST(count(*) AS INT) as uses, fk_agent, CASE WHEN CONVENIO = 'SUS' THEN true ELSE false END AS is_sus\ + FROM machineuse\ + WHERE status in (SELECT * from executed_status)\ + GROUP BY date, fk_agent, is_sus\ + ORDER BY date),\ + range_dates as (SELECT DATE_TRUNC ('year', GENERATE_SERIES (MIN(DT_AGENDA), MAX(DT_AGENDA), '1 year'))::timestamp AS date FROM machineuse as m1),\ + range_fks as (SELECT DISTINCT fk_agent FROM machineuse),\ + markers as (SELECT * FROM true_false_table,range_fks,range_dates),\ + null_rows as (SELECT *, '0'::int as uses FROM markers),\ + res as (SELECT date,uses,fk_agent,is_sus FROM trunc UNION SELECT date,uses,fk_agent,is_sus FROM null_rows)\ + SELECT date,MAX(uses) as uses, fk_agent,is_sus from res\ + GROUP BY date,fk_agent,is_sus\ + ORDER BY date;" + ); + + pgm.createMaterializedView( "agentusesmonthbystatus", {}, + "WITH\ + trunc as (SELECT date_trunc('month', DT_AGENDA) AS date, CAST(count(*) AS INT) as uses, fk_agent, CASE WHEN CONVENIO = 'SUS' THEN true ELSE false END AS is_sus\ + FROM machineuse\ + WHERE status in (SELECT * from executed_status)\ + GROUP BY date, fk_agent, is_sus\ + ORDER BY date),\ + range_dates as (SELECT DATE_TRUNC ('month', GENERATE_SERIES (MIN(DT_AGENDA), MAX(DT_AGENDA), '1 month'))::timestamp AS date FROM machineuse as m1),\ + range_fks as (SELECT DISTINCT fk_agent FROM machineuse),\ + markers as (SELECT * FROM true_false_table,range_fks,range_dates),\ + null_rows as (SELECT *, '0'::int as uses FROM markers),\ + res as (SELECT date,uses,fk_agent,is_sus FROM trunc UNION SELECT date,uses,fk_agent,is_sus FROM null_rows)\ + SELECT date,MAX(uses) as uses, fk_agent,is_sus from res\ + GROUP BY date,fk_agent,is_sus\ + ORDER BY date;" + ); + + pgm.createMaterializedView( "agentusesdaybystatus", {}, + "WITH\ + trunc as (SELECT date_trunc('day', DT_AGENDA) AS date, CAST(count(*) AS INT) as uses, fk_agent, CASE WHEN CONVENIO = 'SUS' THEN true ELSE false END AS is_sus\ + FROM machineuse\ + WHERE status in (SELECT * from executed_status)\ + GROUP BY date, fk_agent, is_sus\ + ORDER BY date),\ + range_dates as (SELECT DATE_TRUNC ('day', GENERATE_SERIES (MIN(DT_AGENDA), MAX(DT_AGENDA), '1 day'))::timestamp AS date FROM machineuse as m1),\ + range_fks as (SELECT DISTINCT fk_agent FROM machineuse),\ + markers as (SELECT * FROM true_false_table,range_fks,range_dates),\ + null_rows as (SELECT *, '0'::int as uses FROM markers),\ + res as (SELECT date,uses,fk_agent,is_sus FROM trunc UNION SELECT date,uses,fk_agent,is_sus FROM null_rows)\ + SELECT date,MAX(uses) as uses, fk_agent,is_sus from res\ + GROUP BY date,fk_agent,is_sus\ + ORDER BY date;" + ); + + +}; + +exports.down = (pgm) => { + // Drop all created tables in this migrate + pgm.dropMaterializedView( "agentusesyearbystatus", {} ); + pgm.dropMaterializedView( "agentusesmonthbystatus", {} ); + pgm.dropMaterializedView( "agentusesdaybystatus", {} ); + pgm.dropTable( "executed_status"); +}; diff --git a/db/package.json b/db/package.json new file mode 100644 index 0000000000000000000000000000000000000000..f99f5de7d3811595cf41ae42e2103a6b98387552 --- /dev/null +++ b/db/package.json @@ -0,0 +1,17 @@ +{ + "name": "db-pinsis", + "version": "1.0.0", + "description": "", + "main": "", + "dependencies": { + "node-pg-migrate": "^3.0.0", + "pg": "^7.4.1" + }, + "devDependencies": {}, + "scripts": { + "start": "nodejs src/main.js", + "migrate": "node-pg-migrate" + }, + "author": "Bruno Henrique Meyer <bruno.meyer@ufpr.br>", + "license": "GPL-3.0" +}