From a9abc5926907b0cf2d9a67f831dc4fa6c6514390 Mon Sep 17 00:00:00 2001 From: Ricky Ng-Adam Date: Fri, 4 May 2018 14:58:24 +0800 Subject: [PATCH] issue #22: fixes for deployment to Heroku --- server/README.md | 22 +- .../003-psql-create-extensions-localhost.sql | 2 + server/sql/005-psql-create-extensions.sql | 4 +- server/sql/050-psql-create-postgraphql.sql | 2 +- server/sql/PSQL.sql | 2 +- server/sql/incoming/people.sql | 21 +- server/sql/model/incoming_to_model.sql | 476 +++++++++--------- server/sql/postgraphql.sql | 9 - server/sql/postgraphql/postgraphql.sql | 18 + server/sql/report/report.sql | 72 +-- server/sql/test/test.utils.sql | 2 - 11 files changed, 330 insertions(+), 300 deletions(-) create mode 100644 server/sql/003-psql-create-extensions-localhost.sql delete mode 100644 server/sql/postgraphql.sql create mode 100644 server/sql/postgraphql/postgraphql.sql diff --git a/server/README.md b/server/README.md index c82f9e9..14ce05a 100644 --- a/server/README.md +++ b/server/README.md @@ -96,13 +96,27 @@ Because Heroku requires the app to be in the root, we use subtree to push: git subtree push --prefix server heroku master ``` +Updating schema: + +```bash +psql -v "ON_ERROR_STOP=1" -b -1 -e -f sql/PSQL.sql `heroku pg:credentials:url | tail -1` +``` + +Restarting the dyno (to load changes to the database for example) + +```bash +heroku restart -a coderbunker-timesheet +``` + +## data transfer to/from heroku + Pushing the local database: ```bash heroku pg:push timesheet postgresql-rigid-65921 --app coderbunker-timesheet ``` -Puling the Heroku database locally and making a copy before changing the pulled version +Pulling the Heroku database locally and making a copy before changing the pulled version (adjust date): ```bash @@ -110,12 +124,6 @@ heroku pg:pull postgresql-rigid-65921 heroku-timesheet --app coderbunker-timeshe psql -c 'CREATE DATABASE "heroku-timesheet-20180416" TEMPLATE "heroku-timesheet";' postgres ``` - -Restarting the dyno (to load changes to the database for example) - -```bash -heroku restart -a coderbunker-timesheet -``` ## Manage Domain ### CNAME Setup for Heroku app diff --git a/server/sql/003-psql-create-extensions-localhost.sql b/server/sql/003-psql-create-extensions-localhost.sql new file mode 100644 index 0000000..1b65d3d --- /dev/null +++ b/server/sql/003-psql-create-extensions-localhost.sql @@ -0,0 +1,2 @@ +CREATE EXTENSION IF NOT EXISTS pgtap; +CREATE EXTENSION IF NOT EXISTS postgres_fdw; \ No newline at end of file diff --git a/server/sql/005-psql-create-extensions.sql b/server/sql/005-psql-create-extensions.sql index 4a5824a..48a3c28 100644 --- a/server/sql/005-psql-create-extensions.sql +++ b/server/sql/005-psql-create-extensions.sql @@ -1,8 +1,8 @@ CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -CREATE EXTENSION IF NOT EXISTS postgres_fdw; +-- CREATE EXTENSION IF NOT EXISTS postgres_fdw; CREATE EXTENSION IF NOT EXISTS unaccent; CREATE EXTENSION IF NOT EXISTS pgcrypto; CREATE EXTENSION IF NOT EXISTS citext; CREATE EXTENSION IF NOT EXISTS citext; -CREATE EXTENSION IF NOT EXISTS pgtap; +-- CREATE EXTENSION IF NOT EXISTS pgtap; diff --git a/server/sql/050-psql-create-postgraphql.sql b/server/sql/050-psql-create-postgraphql.sql index 235872e..f22848c 100644 --- a/server/sql/050-psql-create-postgraphql.sql +++ b/server/sql/050-psql-create-postgraphql.sql @@ -1,3 +1,3 @@ -- postgraphql interface -\ir postgraphql.sql \ No newline at end of file +\ir postgraphql/postgraphql.sql \ No newline at end of file diff --git a/server/sql/PSQL.sql b/server/sql/PSQL.sql index f06c2d6..b46416b 100644 --- a/server/sql/PSQL.sql +++ b/server/sql/PSQL.sql @@ -9,4 +9,4 @@ \ir 030-psql-incoming-to-model.sql \ir 040-psql-create-reports.sql \ir 050-psql-create-postgraphql.sql -\ir 900-psql-testsuite.sql \ No newline at end of file +-- \ir 900-psql-testsuite.sql \ No newline at end of file diff --git a/server/sql/incoming/people.sql b/server/sql/incoming/people.sql index 8dc7015..a48e30d 100644 --- a/server/sql/incoming/people.sql +++ b/server/sql/incoming/people.sql @@ -17,12 +17,21 @@ CREATE OR REPLACE VIEW incoming.people_project AS FROM incoming.raw_people ; -DROP MATERIALIZED VIEW IF EXISTS incoming.nickname_to_email CASCADE; -CREATE MATERIALIZED VIEW incoming.nickname_to_email AS - SELECT resource, email - FROM incoming.people_project - WHERE resource IS NOT NULL - GROUP BY resource, email; +DO $$ + BEGIN + PERFORM * FROM pg_catalog.pg_matviews WHERE matviewname = 'nickname_to_email' AND schemaname = 'incoming'; + IF NOT FOUND THEN + CREATE MATERIALIZED VIEW incoming.nickname_to_email AS + SELECT resource, email + FROM incoming.people_project + WHERE resource IS NOT NULL + GROUP BY resource, email; + CREATE UNIQUE INDEX nickname_to_email_index ON incoming.nickname_to_email(resource, email); + ELSE + REFRESH MATERIALIZED VIEW CONCURRENTLY incoming.nickname_to_email; + END IF; + END; +$$ LANGUAGE PLPGSQL; CREATE OR REPLACE VIEW incoming.people AS SELECT diff --git a/server/sql/model/incoming_to_model.sql b/server/sql/model/incoming_to_model.sql index 07e359f..d82a8c5 100644 --- a/server/sql/model/incoming_to_model.sql +++ b/server/sql/model/incoming_to_model.sql @@ -1,235 +1,259 @@ CREATE OR REPLACE FUNCTION model.convert_incoming_to_model(_id TEXT) RETURNS SETOF model.entry AS $convert_incoming_to_model$ -INSERT INTO model.person(name, email, properties) SELECT * FROM ( - WITH properties AS ( - SELECT - people.fullname AS name, - utils.safe_cast(incoming.profile.email, null::model.email) AS email, - ARRAY[ - 'wechat', - 'github', - 'status', - 'default_rate', - 'default_currency', - 'nicknames', - 'altnames' - ] AS names, - array[ - to_jsonb(wechat), - to_jsonb((regexp_match(COALESCE(people.github, profile.github), '(\w*)$'))[1]), - to_jsonb(status), - to_jsonb((regexp_matches(COALESCE(rate, '250'), '[0-9]*\.?[0-9]'))[1]::NUMERIC), - to_jsonb((regexp_matches(COALESCE(rate, 'RMB'), '(RMB|USD|SGD|EUR)'))[1]), - to_jsonb(nicknames), - to_jsonb(people.altnames) - ] AS values - FROM incoming.people - FULL OUTER join incoming.profile - ON people.email = profile.email - ) - SELECT name, email, jsonb_object_agg(pname, pvalue) AS properties - FROM properties - LEFT JOIN LATERAL UNNEST(properties.names, properties.values) AS p(pname, pvalue) - ON TRUE - WHERE pvalue IS NOT null - GROUP BY name, email -) converted -ON CONFLICT(email) - DO UPDATE SET properties = EXCLUDED.properties - WHERE person.email = EXCLUDED.email - AND person.properties != EXCLUDED.properties -; - -WITH vendor AS ( - SELECT id - FROM model.organization WHERE name = 'Coderbunker Shanghai' -), customer AS ( - SELECT id, name - FROM model.organization -), properties AS ( - SELECT - client AS customer_name, - ARRAY[ - 'status', - 'summary', - 'docid', - 'legal_name' - ] AS names, - array[ - to_jsonb(status), - to_jsonb(summary), - to_jsonb(project_id), - to_jsonb(legal_name) - ] AS values - FROM incoming.account - WHERE project_id = _id - ) -INSERT INTO model.account(name, customer_id, vendor_id, properties) - SELECT customer_name, customer.id, vendor.id, jsonb_object_agg(pname, pvalue) AS properties - FROM vendor, customer, properties - LEFT JOIN LATERAL UNNEST(properties.names, properties.values) AS p(pname, pvalue) - ON TRUE - WHERE pvalue IS NOT NULL AND customer.name = customer_name - GROUP BY customer_name, customer.id, vendor.id -ON CONFLICT(name) - DO UPDATE SET properties = EXCLUDED.properties - WHERE account.name = EXCLUDED.name - AND account.properties != EXCLUDED.properties -; - -INSERT INTO model.project(name, properties, account_id) SELECT * FROM ( - WITH properties AS ( - SELECT - id AS docid, - name AS project_name, - ARRAY[ - 'docid', - 'last_update' - ] AS names, - array[ - to_jsonb(id), - to_jsonb(last_update) - ] AS values - FROM incoming.project - WHERE id = _id - ) - SELECT project_name AS name, jsonb_object_agg(pname, pvalue) AS properties, account.id AS account_id - FROM properties - LEFT JOIN LATERAL UNNEST(properties.names, properties.values) AS p(pname, pvalue) ON TRUE - LEFT JOIN model.account ON account.properties->>'docid' = docid - WHERE pvalue IS NOT NULL AND account.properties IS NOT null - GROUP BY project_name, account.id -) converted -ON CONFLICT(name) - DO UPDATE SET properties = EXCLUDED.properties - WHERE project.properties->>'docid' = EXCLUDED.properties->>'docid' - AND project.properties != EXCLUDED.properties -; - -INSERT INTO model.membership(project_id, person_id, name, properties) SELECT * FROM ( - WITH properties AS ( + INSERT INTO model.organization(name, properties) + SELECT * FROM ( + WITH properties AS ( + SELECT + account.client AS name, + ARRAY[ + 'legal_name' + ] AS names, + array[ + to_jsonb(legal_name) + ] AS values + FROM incoming.account + ) + SELECT name, jsonb_object_agg(pname, pvalue) AS properties + FROM properties + LEFT JOIN LATERAL UNNEST(properties.names, properties.values) AS p(pname, pvalue) + ON TRUE + WHERE pvalue IS NOT null + GROUP BY name + ) converted + ON CONFLICT(name) + DO UPDATE SET properties = EXCLUDED.properties WHERE organization.properties != EXCLUDED.properties + ; + + INSERT INTO model.person(name, email, properties) SELECT * FROM ( + WITH properties AS ( + SELECT + people.fullname AS name, + utils.safe_cast(incoming.profile.email, null::model.email) AS email, + ARRAY[ + 'wechat', + 'github', + 'status', + 'default_rate', + 'default_currency', + 'nicknames', + 'altnames' + ] AS names, + array[ + to_jsonb(wechat), + to_jsonb((regexp_match(COALESCE(people.github, profile.github), '(\w*)$'))[1]), + to_jsonb(status), + to_jsonb((regexp_matches(COALESCE(rate, '250'), '[0-9]*\.?[0-9]'))[1]::NUMERIC), + to_jsonb((regexp_matches(COALESCE(rate, 'RMB'), '(RMB|USD|SGD|EUR)'))[1]), + to_jsonb(nicknames), + to_jsonb(people.altnames) + ] AS values + FROM incoming.people + FULL OUTER join incoming.profile + ON people.email = profile.email + ) + SELECT name, email, jsonb_object_agg(pname, pvalue) AS properties + FROM properties + LEFT JOIN LATERAL UNNEST(properties.names, properties.values) AS p(pname, pvalue) + ON TRUE + WHERE pvalue IS NOT null + GROUP BY name, email + ) converted + ON CONFLICT(email) + DO UPDATE SET properties = EXCLUDED.properties + WHERE person.email = EXCLUDED.email + AND person.properties != EXCLUDED.properties + ; + + WITH vendor AS ( + SELECT id + FROM model.organization WHERE name = 'Coderbunker Shanghai' + ), customer AS ( + SELECT id, name + FROM model.organization + ), properties AS ( + SELECT + client AS customer_name, + ARRAY[ + 'status', + 'summary', + 'docid', + 'legal_name' + ] AS names, + array[ + to_jsonb(status), + to_jsonb(summary), + to_jsonb(project_id), + to_jsonb(legal_name) + ] AS values + FROM incoming.account + WHERE project_id = _id + ) + INSERT INTO model.account(name, customer_id, vendor_id, properties) + SELECT customer_name, customer.id, vendor.id, jsonb_object_agg(pname, pvalue) AS properties + FROM vendor, customer, properties + LEFT JOIN LATERAL UNNEST(properties.names, properties.values) AS p(pname, pvalue) + ON TRUE + WHERE pvalue IS NOT NULL AND customer.name = customer_name + GROUP BY customer_name, customer.id, vendor.id + ON CONFLICT(name) + DO UPDATE SET properties = EXCLUDED.properties + WHERE account.name = EXCLUDED.name + AND account.properties != EXCLUDED.properties + ; + + INSERT INTO model.project(name, properties, account_id) SELECT * FROM ( + WITH properties AS ( + SELECT + id AS docid, + name AS project_name, + ARRAY[ + 'docid', + 'last_update' + ] AS names, + array[ + to_jsonb(id), + to_jsonb(last_update) + ] AS values + FROM incoming.project + WHERE id = _id + ) + SELECT project_name AS name, jsonb_object_agg(pname, pvalue) AS properties, account.id AS account_id + FROM properties + LEFT JOIN LATERAL UNNEST(properties.names, properties.values) AS p(pname, pvalue) ON TRUE + LEFT JOIN model.account ON account.properties->>'docid' = _id + WHERE pvalue IS NOT NULL AND account.properties IS NOT null + GROUP BY project_name, account.id + ) converted + ON CONFLICT(name) + DO UPDATE SET properties = EXCLUDED.properties + WHERE project.properties->>'docid' = EXCLUDED.properties->>'docid' + AND project.properties != EXCLUDED.properties + ; + + INSERT INTO model.membership(project_id, person_id, name, properties) SELECT * FROM ( + WITH properties AS ( + SELECT + resource, + person.id AS person_id, + project.id AS project_id, + ARRAY[ + 'email', + 'docid' + ] AS names, + array[ + to_jsonb(person.email), + to_jsonb(people_project.project_id) + ] AS values + FROM incoming.people_project + LEFT JOIN model.person ON people_project.email = person.email + LEFT JOIN model.project ON people_project.project_id = project.properties->>'docid' + WHERE + project.id IS NOT NULL AND + person.id IS NOT NULL AND + people_project.project_id = _id + ) + SELECT project_id, person_id, resource AS name, jsonb_object_agg(pname, pvalue) AS properties + FROM properties + LEFT JOIN LATERAL UNNEST(properties.names, properties.values) AS p(pname, pvalue) ON TRUE + WHERE pvalue IS NOT NULL + GROUP BY project_id, person_id, resource + ) converted + ON CONFLICT(project_id, name) + DO NOTHING + ; + + INSERT INTO model.rate(membership_id, rate, discount, currency, basis, valid) SELECT * FROM ( + WITH project_rate_validity AS ( + -- TODO: need to manage validity period + SELECT project_id, resource, min(COALESCE(start_datetime, now())) AS start_datetime + FROM incoming.entry + WHERE project_id = _id + GROUP BY project_id, resource + HAVING min(start_datetime) IS NOT NULL + ) SELECT - resource, - person.id AS person_id, - project.id AS project_id, - ARRAY[ - 'email', - 'docid' - ] AS names, - array[ - to_jsonb(person.email), - to_jsonb(people_project.project_id) - ] AS values - FROM incoming.people_project - LEFT JOIN model.person ON people_project.email = person.email - LEFT JOIN model.project ON people_project.project_id = project.properties->>'docid' - WHERE - project.id IS NOT NULL AND - person.id IS NOT NULL AND - people_project.project_id = _id - ) - SELECT project_id, person_id, resource AS name, jsonb_object_agg(pname, pvalue) AS properties - FROM properties - LEFT JOIN LATERAL UNNEST(properties.names, properties.values) AS p(pname, pvalue) ON TRUE - WHERE pvalue IS NOT NULL - GROUP BY project_id, person_id, resource -) converted -ON CONFLICT(project_id, name) - DO NOTHING -; - -INSERT INTO model.rate(membership_id, rate, discount, currency, basis, valid) SELECT * FROM ( - WITH project_rate_validity AS ( - -- TODO: need to manage validity period - SELECT project_id, resource, min(COALESCE(start_datetime, now())) AS start_datetime + membership.id AS membership_id, + project_rate AS rate, + COALESCE(people_project.project_rate_discount, 0.0)::NUMERIC AS discount, + 'RMB' AS currency, -- TODO: get it from default_currency + 'hourly' AS basis, + start_datetime AS valid + FROM model.membership + -- TODO: warn on missing entries + INNER JOIN incoming.people_project + ON membership.properties->>'docid' = people_project.project_id + AND membership.name = people_project.resource + INNER JOIN project_rate_validity + ON membership.properties->>'docid' = project_rate_validity.project_id + AND membership.name = project_rate_validity.resource + WHERE people_project.project_id = _id AND project_rate IS NOT NULL + + ) converted + ON CONFLICT(membership_id, basis) + DO UPDATE SET discount = EXCLUDED.discount + WHERE rate.membership_id = EXCLUDED.membership_id + AND rate.basis = EXCLUDED.basis + AND rate.discount != EXCLUDED.discount + ; + + INSERT INTO model.task(project_id, name) SELECT * FROM ( + WITH tasks AS ( + SELECT + DISTINCT(project_id, taskname), + project_id, + taskname FROM incoming.entry - WHERE project_id = _id - GROUP BY project_id, resource - HAVING min(start_datetime) IS NOT NULL - ) - SELECT - membership.id AS membership_id, - project_rate AS rate, - COALESCE(people_project.project_rate_discount, 0.0)::NUMERIC AS discount, - 'RMB' AS currency, -- TODO: get it from default_currency - 'hourly' AS basis, - start_datetime AS valid - FROM model.membership - -- TODO: warn on missing entries - INNER JOIN incoming.people_project - ON membership.properties->>'docid' = people_project.project_id - AND membership.name = people_project.resource - INNER JOIN project_rate_validity - ON membership.properties->>'docid' = project_rate_validity.project_id - AND membership.name = project_rate_validity.resource - WHERE people_project.project_id = _id - -) converted -ON CONFLICT(membership_id, basis) - DO UPDATE SET discount = EXCLUDED.discount - WHERE rate.membership_id = EXCLUDED.membership_id - AND rate.basis = EXCLUDED.basis - AND rate.discount != EXCLUDED.discount -; - -INSERT INTO model.task(project_id, name) SELECT * FROM ( - WITH tasks AS ( + WHERE + taskname IS NOT NULL + AND length(trim(taskname)) > 0 + AND lower(taskname) != 'Deposit' + AND project_id = _id + GROUP BY project_id, taskname + ) SELECT - DISTINCT(project_id, taskname), - project_id, - taskname - FROM incoming.entry - WHERE - taskname IS NOT NULL - AND length(trim(taskname)) > 0 - AND lower(taskname) != 'Deposit' - AND project_id = _id - GROUP BY project_id, taskname + model.project.id AS project_id, + taskname AS name + FROM tasks + INNER JOIN model.project + ON tasks.project_id = model.project.properties->>'docid' + ) converted + ON CONFLICT(project_id, name) + DO NOTHING + ; + + WITH incoming_timesheet AS ( + SELECT entry.* + FROM incoming.entry_union AS entry + INNER JOIN incoming.project + ON project.id = entry.project_id + INNER JOIN incoming.people_project + ON incoming.project.id = people_project.project_id + AND people_project.resource = entry.resource + -- some entries are for accounting purposes + WHERE + project.id = _id AND + start_datetime IS NOT NULL AND + stop_datetime IS NOT NULL AND + (stop_datetime - start_datetime) < INTERVAL '14 hours' ) - SELECT - model.project.id AS project_id, - taskname AS name - FROM tasks - INNER JOIN model.project - ON tasks.project_id = model.project.properties->>'docid' -) converted -ON CONFLICT(project_id, name) - DO NOTHING -; - -WITH incoming_timesheet AS ( - SELECT entry.* - FROM incoming.entry_union AS entry - INNER JOIN incoming.project - ON project.id = entry.project_id - INNER JOIN incoming.people_project - ON incoming.project.id = people_project.project_id - AND people_project.resource = entry.resource - -- some entries are for accounting purposes - WHERE - project.id = _id AND - start_datetime IS NOT NULL AND - stop_datetime IS NOT NULL AND - (stop_datetime - start_datetime) < INTERVAL '14 hours' -) -INSERT INTO model.entry(membership_id, task_id, start_datetime, stop_datetime) - SELECT - membership.id AS membership_id, - task.id AS task_id, - start_datetime, - stop_datetime - FROM incoming_timesheet - INNER JOIN model.project - ON model.project.properties->>'docid' = incoming_timesheet.project_id - INNER JOIN model.membership - ON incoming_timesheet.resource = membership.name AND membership.project_id = model.project.id - INNER JOIN model.task - ON task.project_id = model.project.id - AND task.name = taskname - WHERE model.project.properties->>'docid' = _id -ON CONFLICT(membership_id, start_datetime, stop_datetime) - DO NOTHING -RETURNING * + INSERT INTO model.entry(membership_id, task_id, start_datetime, stop_datetime) + SELECT + membership.id AS membership_id, + task.id AS task_id, + start_datetime, + stop_datetime + FROM incoming_timesheet + INNER JOIN model.project + ON model.project.properties->>'docid' = incoming_timesheet.project_id + INNER JOIN model.membership + ON incoming_timesheet.resource = membership.name AND membership.project_id = model.project.id + INNER JOIN model.task + ON task.project_id = model.project.id + AND task.name = taskname + WHERE model.project.properties->>'docid' = _id + ON CONFLICT(membership_id, start_datetime, stop_datetime) + DO NOTHING + RETURNING * ; $convert_incoming_to_model$ LANGUAGE SQL; diff --git a/server/sql/postgraphql.sql b/server/sql/postgraphql.sql deleted file mode 100644 index 29cbbc2..0000000 --- a/server/sql/postgraphql.sql +++ /dev/null @@ -1,9 +0,0 @@ -CREATE SCHEMA IF NOT EXISTS postgraphql; - -DROP MATERIALIZED VIEW IF EXISTS postgraphql.organization; -CREATE MATERIALIZED VIEW postgraphql.organization AS - SELECT - organization.*, - now() AS last_refresh, - (SELECT max(last_update) FROM incoming.project) AS last_update - FROM report.organization; \ No newline at end of file diff --git a/server/sql/postgraphql/postgraphql.sql b/server/sql/postgraphql/postgraphql.sql new file mode 100644 index 0000000..90084bd --- /dev/null +++ b/server/sql/postgraphql/postgraphql.sql @@ -0,0 +1,18 @@ +CREATE SCHEMA IF NOT EXISTS postgraphql; + +DO $$ + BEGIN + PERFORM * FROM pg_catalog.pg_matviews WHERE matviewname = 'organization' AND schemaname = 'postgraphql'; + IF NOT FOUND THEN + CREATE MATERIALIZED VIEW postgraphql.organization AS + SELECT + organization.*, + now() AS last_refresh, + (SELECT max(last_update) FROM incoming.project) AS last_update + FROM report.organization; + CREATE UNIQUE INDEX postgraphql_organization_index ON postgraphql.organization(orgname); + ELSE + REFRESH MATERIALIZED VIEW CONCURRENTLY postgraphql.organization; + END IF; + END; +$$ LANGUAGE PLPGSQL; diff --git a/server/sql/report/report.sql b/server/sql/report/report.sql index 3f6506d..913cba1 100644 --- a/server/sql/report/report.sql +++ b/server/sql/report/report.sql @@ -1,49 +1,36 @@ CREATE SCHEMA IF NOT EXISTS report; -DROP VIEW IF EXISTS report.organization CASCADE; CREATE OR REPLACE VIEW report.organization AS - WITH person_summary AS ( - SELECT - COUNT(distinct(person_id)) AS count - FROM model.membership - ), project_summary AS ( - SELECT - COUNT(*) AS count - FROM model.project - ), account_summary AS ( - SELECT count(*) + WITH account_summary AS ( + SELECT vendor_id, count(*) AS active_account FROM model.account - WHERE account.properties->>'status' = 'Ongoing' - ), timesheet_summary AS ( + WHERE + account.properties->>'status' = 'Ongoing' + GROUP BY account.vendor_id + ) + SELECT + *, + round((total_hours/168)::NUMERIC) AS total_eng_months + FROM ( SELECT + vendor_name AS orgname, min(start_datetime) AS since, + age(now(), min(start_datetime))::text AS activity, + count(DISTINCT(person_id)) AS people_count, + count(DISTINCT(project_id)) AS project_count, + active_account AS ongoing_project_count, extract(HOUR FROM sum(duration)) AS total_hours, - sum(total) AS total_gross, - sum(total_discount) AS total_investment, - age(now(), min(start_datetime))::text AS activity - FROM model.timesheet - ) - SELECT - timesheet.vendor_name AS orgname, - timesheet_summary.since, - timesheet_summary.activity, - person_summary.count AS people_count, - project_summary.count AS project_count, - account_summary.count AS ongoing_project_count, - timesheet_summary.total_hours AS total_hours, - ((timesheet_summary.total_hours)/168)::integer AS total_eng_months, - timesheet_summary.total_gross, - timesheet_summary.total_investment - FROM - model.timesheet, - person_summary, - project_summary, - account_summary, - timesheet_summary - LIMIT 1 - ; + round(sum(total), 2) AS total_gross, + round(sum(total_discount), 2) AS total_investment + FROM model.timesheet, + LATERAL ( + SELECT active_account + FROM account_summary + WHERE account_summary.vendor_id = timesheet.vendor_id + ) a + GROUP BY vendor_name, active_account + ) t; -DROP VIEW IF EXISTS report.project CASCADE; CREATE OR REPLACE VIEW report.project AS SELECT project_id, @@ -66,7 +53,6 @@ CREATE OR REPLACE VIEW report.project AS ORDER BY total_gross DESC ; -DROP VIEW IF EXISTS report.person CASCADE; CREATE OR REPLACE VIEW report.person AS SELECT person_id, @@ -85,10 +71,4 @@ CREATE OR REPLACE VIEW report.person AS FROM model.timesheet GROUP BY person_id, person_name ORDER BY total_gross DESC - ; - ---DROP VIEW IF EXISTS report.balance CASCADE; ---CREATE OR REPLACE VIEW report.balance AS - SELECT * - FROM model.account - INNER JOIN model.ledger ON (account.id = ledger.target_id); \ No newline at end of file + ; \ No newline at end of file diff --git a/server/sql/test/test.utils.sql b/server/sql/test/test.utils.sql index 2f80ff3..8c77f9d 100644 --- a/server/sql/test/test.utils.sql +++ b/server/sql/test/test.utils.sql @@ -1,5 +1,3 @@ -CREATE SCHEMA IF NOT EXISTS test; - CREATE OR REPLACE FUNCTION test.count_all_views( schemaname TEXT ) RETURNS SETOF TEXT AS $$