Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Enhance export API endpoint (#840) #858

Merged
merged 2 commits into from
Jul 11, 2023
Merged
Show file tree
Hide file tree
Changes from all 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
Original file line number Diff line number Diff line change
@@ -0,0 +1,92 @@
exports.up = function(knex) {
return Promise.resolve()
.then(() => knex.schema.dropViewIfExists('submissions_data_vw'))
.then(() => knex.schema.raw(`create or replace view submissions_data_vw as
select
s."confirmationId",
s."formName",
s.version,
s."createdAt",
case
when u.id is null then 'public'::varchar(255)
else u."fullName"
end as "fullName",
case
when u.id is null then 'public'::varchar(255)
else u.username
end as "username",
u.email,
fs.submission -> 'data' as "submission",
fs."updatedAt",
s.deleted,
s.draft,
s."submissionId",
s."formId",
s."formVersionId",
u.id as "userId",
u."idpUserId",
u."firstName",
u."lastName",
s."formSubmissionStatusCode" as "status",
s."formSubmissionAssignedToFullName" as "assignee",
s."formSubmissionAssignedToEmail" as "assigneeEmail"
from
submissions_vw s
inner join form_submission fs on
s."submissionId" = fs.id
left outer join form_submission_user fsu on
s."submissionId" = fsu."formSubmissionId"
and fsu.permission = 'submission_create'
left outer join "user" u on
fsu."userId" = u.id
order by
s."createdAt",
s."formName",
s.version`));
};

exports.down = function(knex) {
return Promise.resolve()
.then(() => knex.schema.dropViewIfExists('submissions_data_vw'))
.then(() => knex.schema.raw(`create or replace view submissions_data_vw as
select
s."confirmationId",
s."formName",
s.version,
s."createdAt",
case
when u.id is null then 'public'::varchar(255)
else u."fullName"
end as "fullName",
case
when u.id is null then 'public'::varchar(255)
else u.username
end as "username",
u.email,
fs.submission -> 'data' as "submission",
s.deleted,
s.draft,
s."submissionId",
s."formId",
s."formVersionId",
u.id as "userId",
u."idpUserId",
u."firstName",
u."lastName",
s."formSubmissionStatusCode" as "status",
s."formSubmissionAssignedToFullName" as "assignee",
s."formSubmissionAssignedToEmail" as "assigneeEmail"
from
submissions_vw s
inner join form_submission fs on
s."submissionId" = fs.id
left outer join form_submission_user fsu on
s."submissionId" = fsu."formSubmissionId"
and fsu.permission = 'submission_create'
left outer join "user" u on
fsu."userId" = u.id
order by
s."createdAt",
s."formName",
s.version`));
};
38 changes: 30 additions & 8 deletions app/src/docs/v1.api-spec.yaml
Original file line number Diff line number Diff line change
Expand Up @@ -337,17 +337,39 @@ paths:
example: 1
required: true
- in: query
name: minDate
name: preference
schema:
type: string
example: '2020-12-17T08:00:00Z'
description: Start date of period included in the export
type: object
example: '{ minDate=2020-12-17T08:00:00Z, maxDate=2020-12-17T08:00:00Z, updatedMinDate=2020-12-17T08:00:00Z, updatedMaxDate=2020-12-17T08:00:00Z }'
description: form submissions export preferences
- in: query
name: deleted
schema:
type: Boolean
description: (optional) This optional parameter should be set to true if deleted records (submissions) need to be fetched
example: false
- in: query
name: maxDate
name: drafts
schema:
type: Boolean
description: (optional) This optional parameter should be set to true if draft records (submissions) need to be fetched
example: false
- in: query
name: columns
schema:
type: array
description: (optional) List of form level columns (Only Allowed draft, deleted, updatedAt columns) to be include. Other then allowed columns will be ignored
example:
- draft,
- deleted,
- updatedAt
- in: query
name: status
schema:
type: string
example: '2020-12-17T08:00:00Z'
description: End date of period included in the export
description: Submission status to be filtered based on
example: COMPLETED
required: false
responses:
'200':
description: Export file created for download
Expand Down Expand Up @@ -3172,7 +3194,7 @@ components:
type: String
description: default value is submissions and should be changed
example: submissions
preferences:
preference:
type: object
description: form submissions export preferences
example: { minDate, maxDate }
Expand Down
14 changes: 14 additions & 0 deletions app/src/forms/common/models/views/submissionData.js
Original file line number Diff line number Diff line change
Expand Up @@ -21,6 +21,20 @@ class SubmissionData extends Model {
query.where('createdAt', '<=', maxDate);
}
},
filterUpdatedAt(query, minDate, maxDate) {
if (minDate && maxDate) {
query.whereBetween('updatedAt', [minDate, maxDate]);
} else if (minDate) {
query.where('updatedAt', '>=', minDate);
} else if (maxDate) {
query.where('updatedAt', '<=', maxDate);
}
},
filterStatus(query, value) {
if (value) {
query.where('status', value);
}
},
filterDeleted(query, value) {
if (!value) {
query.where('deleted', false);
Expand Down
28 changes: 21 additions & 7 deletions app/src/forms/form/exportService.js
Original file line number Diff line number Diff line change
Expand Up @@ -138,13 +138,18 @@ const service = {
return `${form.snake()}_${type}.${format}`.toLowerCase();
},

_submissionsColumns: (form) => {
_submissionsColumns: (form, params) => {
// Custom columns not defined - return default column selection behavior
let columns = ['confirmationId', 'formName', 'version', 'createdAt', 'fullName', 'username', 'email'];
// if form has 'status updates' enabled in the form settings include these in export
if (form.enableStatusUpdates) {
columns = columns.concat(['status', 'assignee', 'assigneeEmail']);
}
// Let's add form level columns like deleted or draft
if (params?.columns?.length) {
let optionalAcceptedColumns = ['draft', 'deleted', 'updatedAt']; //'draft', 'deleted', 'updatedAt' columns needed for ETL process at this moment
columns = columns.concat((Array.isArray(params.columns) ? [...params.columns] : [params.columns]).filter((column) => optionalAcceptedColumns.includes(column)));
}
// and join the submission data
return columns.concat(['submission']);
},
Expand All @@ -155,7 +160,8 @@ const service = {

_getData: async (exportType, formVersion, form, params = {}) => {
if (EXPORT_TYPES.submissions === exportType) {
return service._getSubmissions(form, params, formVersion);
let subs = await service._getSubmissions(form, params, formVersion);
return subs;
}
return {};
},
Expand Down Expand Up @@ -188,16 +194,25 @@ const service = {
} else {
preference = params.preference;
}

// let submissionData;
// params for this export include minDate and maxDate (full timestamp dates).
let submissionData = await SubmissionData.query()
.column(service._submissionsColumns(form, params))
return SubmissionData.query()
.select(service._submissionsColumns(form, params))
.where('formId', form.id)
.modify('filterVersion', version)
.modify('filterCreatedAt', preference && preference.minDate, preference && preference.maxDate)
.modify('filterUpdatedAt', preference && preference.updatedMinDate, preference && preference.updatedMaxDate)
.modify('filterStatus', params.status)
.modify('filterDeleted', params.deleted)
.modify('filterDrafts', params.drafts)
.modify('orderDefault');
.modify('orderDefault')
.then((submissionData) => {
if (submissionData == undefined || submissionData == null || submissionData.length == 0) return [];
return service._submissionFilterByUnsubmit(submissionData);
});
},

_submissionFilterByUnsubmit: (submissionData) => {
for (let index in submissionData) {
let keys = Object.keys(submissionData[index].submission);
for (let key of keys) {
Expand All @@ -208,7 +223,6 @@ const service = {
}
return submissionData;
},

_formatSubmissionsJson: (form, data) => {
return {
data: data,
Expand Down
2 changes: 2 additions & 0 deletions app/tests/common/dbHelper.js
Original file line number Diff line number Diff line change
Expand Up @@ -48,6 +48,8 @@ MockModel.orderBy = jest.fn().mockReturnThis();
MockModel.patch = jest.fn().mockReturnThis();
MockModel.patchAndFetchById = jest.fn().mockReturnThis();
MockModel.query = jest.fn().mockReturnThis();
MockModel.query.select = jest.fn().mockReturnThis();
MockModel.query.column = jest.fn().mockReturnThis();
MockModel.resolve = jest.fn().mockResolvedValue(returnValue);
MockModel.returning = jest.fn().mockReturnThis();
(MockModel.skipUndefined = jest.fn(() => {
Expand Down
Loading