Skip to content

Commit

Permalink
85 - 86 - 87 - Fix medic-users-meta views and make compatible with da…
Browse files Browse the repository at this point in the history
…ily telemetry (#91)

Deprecate old `medic-users-meta` views and create new ones fixing bugs and making compatible with upcoming daily telemetry.

**Issues**: #85 , #86 , #87

**Changes**:

- [Bug] Change the indexes for both views (telemetry and feedback) based on the columns user_name and period_start, the PR remove the unique constraint to avoid collisions, and instead the uuid of the records are used as unique index to allow concurrent refresh of the views (#86).
- [Bug] Fix bug that causes records being parsed with months 0-indexed as 1-indexed and vice versa (thanks to @kitsao ) (#87).
- [Improvement] The column period_start from the telemetry view has the same DATE type, but the day component is parsed from the JSON metadata.day field if present (daily aggregation telemetry from this upcoming CHT feature), otherwise defaulted to 1 as it was before to maintain backward compatibility with monthly aggregation telemetry (#85).

**Affected views**:

- Feedback view: `useview_feedback`
- Telemetry view: `useview_telemetry`
  • Loading branch information
mrsarm authored May 21, 2021
1 parent c43b473 commit 84b4047
Show file tree
Hide file tree
Showing 5 changed files with 1,576 additions and 6 deletions.
10 changes: 5 additions & 5 deletions README.md
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
# medic-couch2pg ![travis](https://travis-ci.org/medic/medic-couch2pg.svg?branch=master)
# medic-couch2pg

Software for creating read-only replicas of CouchDB data inside PostgreSQL v9.4
Software for creating read-only replicas of CouchDB data inside PostgreSQL v9.4.

The focus is specifically on CHT application data currently stored in CouchDB. If you are looking to have a read-only replica of CouchDB data for your application, consider [couch2pg](https://www.npmjs.com/package/couch2pg).

Expand Down Expand Up @@ -64,8 +64,8 @@ Run tests with: `grunt test`.
Run tests in interactive watch mode with: `npm run watch`.

Environment variables required for the integration tests to run correctly:
* `TEST_PG_URL`: postgres url. ie: `http://admin:pass@localhost:5984`
* `TEST_COUCH_URL`: couch url. ie: `postgres://localhost:5432`
* `TEST_PG_URL`: postgres url. ie: `postgres://localhost:5432`
* `TEST_COUCH_URL`: couch url. ie: `http://admin:pass@localhost:5984`

NB: The integration tests destroy and re-create the given databases each time they are run.

Expand All @@ -77,7 +77,7 @@ We support PostgreSQL 9.4 and greater. The user passed in the postgres url needs

## Example usage

You should probably install medic-analytics as a service and leave it to do its thing, as it should be able to run independently without any user input.
You should probably install medic-couch2pg as a service and leave it to do its thing, as it should be able to run independently without any user input.

### Installing as a service using Upstart (Ubuntu 14.4)

Expand Down
59 changes: 59 additions & 0 deletions libs/medic-users-meta/migrations/202105171933.do.86.usersMeta.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,59 @@
-- Drop views with wrong indexes and definitions that were
-- created at 202102191153.do.54-create-couchdb-users-meta-table.sql
DROP MATERIALIZED VIEW IF EXISTS useview_feedback;
DROP MATERIALIZED VIEW IF EXISTS useview_telemetry;

-- The views are created again
CREATE MATERIALIZED VIEW useview_feedback AS
SELECT
doc->>'_id' AS uuid,
doc#>>'{meta,source}' AS SOURCE,
doc#>>'{meta,url}' AS url,
doc#>>'{meta,user,name}' AS user_name,
doc#>>'{meta,time}' AS period_start,
COALESCE(doc#>>'{info,cause}',doc->>'info') AS cause,
doc#>>'{info,message}' AS message
FROM
couchdb_users_meta
WHERE
doc->>'type'='feedback';

CREATE UNIQUE INDEX idx_useview_feedback_uuid ON useview_feedback(uuid); --> Only to allow the refresh of the view CONCURRENTLY
CREATE INDEX idx_useview_feedback_period_start_user ON useview_feedback(period_start,user_name);

CREATE MATERIALIZED VIEW useview_telemetry AS
SELECT
doc->>'_id' AS uuid,
CONCAT_WS( --> Date concatenation from JSON fields, eg. 2021-5-17
'-',
doc#>>'{metadata,year}', --> year
CASE --> month of the year
WHEN
string_to_array(substring(doc#>>'{metadata,versions,app}' FROM '(\d+.\d+.\d+)'),'.')::int[] < '{3,8,0}'::int[]
THEN
(doc#>>'{metadata,month}')::int+1 --> Legacy, months zero-indexed (0 - 11)
ELSE
(doc#>>'{metadata,month}')::int --> Month is between 1 - 12
END,
CASE --> day of the month, else 1
WHEN
(doc#>>'{metadata,day}') IS NOT NULL
THEN
doc#>>'{metadata,day}'
ELSE
'1'
END
)::date AS period_start,
doc#>>'{metadata,user}' AS user_name,
doc#>>'{metadata,versions,app}' AS app_version,
doc#>>'{metrics,boot_time,min}' AS boot_time_min,
doc#>>'{metrics,boot_time,max}' AS boot_time_max,
doc#>>'{metrics,boot_time,count}' AS boot_time_count,
doc#>>'{dbInfo,doc_count}' AS doc_count_on_local_db
FROM
couchdb_users_meta
WHERE
doc->>'type'='telemetry';

CREATE UNIQUE INDEX idx_useview_telemetry_uuid ON useview_telemetry(uuid); --> Only to allow the refresh of the view CONCURRENTLY
CREATE INDEX idx_useview_telemetry_period_start_user ON useview_telemetry(period_start,user_name);
Loading

0 comments on commit 84b4047

Please sign in to comment.