diff --git a/app/services/data/tear-down/README.md b/app/services/data/tear-down/README.md new file mode 100644 index 0000000000..98cb1c5667 --- /dev/null +++ b/app/services/data/tear-down/README.md @@ -0,0 +1,89 @@ +# Tear down + +This function supports our [water-abstraction-acceptance-tests](https://github.com/DEFRA/water-abstraction-acceptance-tests). At the start of each test, it will make an HTTP call to `POST /data/tear-down` resulting in `TearDownService.go()` being called. + +The service and those it calls are responsible for clearing the various schemas we use of test data. Some tables have a `is_test` field that immediately identifies the record as being created for a test. + +But each test will create data that won't be flagged this way. So, the tear-down services also remove records we can identify as being test data. + +- it might be linked to a `is_test` record +- it has a known value, for example, `name`, that is specific to the acceptance tests + +Ideally, we wouldn't need to remove anything between the tests. We could then avoid this step and the delay it causes. But until we re-architect fully the acceptance tests we've inherited we have to work with what we've got. + +When we took on WRLS [water-abstraction-service](https://github.com/DEFRA/water-abstraction-service) had a tear-down endpoint. But it would take more than a minute to complete. This caused the tests to take a long time to finish and often caused them to fail. + +We built a more performant version. It would typically get the job done in 15 to 20 seconds. But sometimes this would creep to 40 seconds which again would cause test runs to fail. + +We are adding this README at the point we've taken a second shot at an even more performant option. We wanted to capture what we tried and the results we got to help + +- explain why this is the current solution +- avoid anyone wasting time trying anything we've already tried +- spark inspiration of an _even better_ way of doing this! + +## Strategies tried + +Including sticking with what we had, we tried 8 separate ways of clearing down the test data. We would run the supplementary billing `journey.cy.js` acceptance test and record the time it took in milliseconds to + +- wipe each of the schemas +- complete all schemas + +We did this a number of times and then averaged out the results. We then selected the one that was most performant overall. + +> This was tested on an Apple M1 Mac. The DB was a complete import of the NALD data including all returns. This explains why the times recorded here (especially for the 'No changes' strategy) might be greater than you see if doing the same thing yourself. + +### No change + +As a bench mark we recorded what the times were using the existing solution. The key issue was clearing the `WATER` schema, which we suspected was due to the numerous foreign key constraints the previous team added. + +When a record is deleted these constraints are triggered and checked. + +### Disable the triggers + +In this attempt the only change we made was to disable all the triggers in a schema first, then leave the existing code run, followed by re-enabling the triggers. + +This was the critical change that got the average completion time down from 42 secs to less than 7 secs. + +### Single query + +The existing functionality would clear down all schemas at the same time using a [Promise.all()](https://developer.mozilla.org/en-US/docs/Web/JavaScript/Reference/Global_Objects/Promise/all). But within each schema's tear-down service the tables would be cleared down one at a time using [Knex.js](https://knexjs.org/). + +We wanted to test if performance was better if we fired a single [raw query](https://knexjs.org/guide/raw.html#raw-queries) at the DB for each schema instead. We retained the trigger disabling strategy because of the impact it had. We simply combined the calls for these with the delete table calls into a single DB query. + +This time we got a small 1 sec improvement in the average time to complete. + +### Promise all + +Next we wanted to test what would happen if instead of firing a [single query per schema](#single-query), we adopted the same `Promise.all()` pattern used at the schema level to the queries inside each schema service. + +We rebuilt all the existing delete functions to just use 'raw' queries. This allowed us to bring the disabling of a table's triggers together with it's delete statement as one request to the DB. + +We then fired them all at the same time using `Promise.all()`, whilst clearing down all schemas at the same time. + +We were concerned that we might be pushing _too much_ at the DB at the same time. But we did see a minor improvement in the average completion time of 100ms. Though it should be noted that the average schema completion time degraded for some schemas. + +### Best of + +Having seen that some schemas performed better when fired as a [single query](#single-query) whereas others got their best times using the [promise all strategy](#promise-all) we tried a 'best of'. + +With this we saw a degradation in completion time of 2 secs. We were also uncomfortable with mixing patterns in the schemas so were happy to see this didn't win out! + +### All in one + +Finally, we tried lumping all the queries we were firing into a single query. Essentially, let the DB do it all and perhaps optimise it better than what we were attempting. + +Again, this confirmed disabling the table triggers still had a massive impact on average completion time as it was vastly quicker than our current implementation. But it was still 2 secs off [Promise all](#promise-all). + +## Results + +> The average times are in milliseconds. Just divide by 1000 for secs, for example, 1770 / 1000 = 1.7 secs + +| Schema | No change | Just triggers | Single Query | Promise all | Best of | All in one | +|---------|-----------|---------------|--------------|-------------|---------|------------| +| CRM | 1770 | 2106 | 1185 | **964** | 1444 | N/A | +| IDM | 58 | 73 | 46 | **852** | 1199 | N/A | +| PERMIT | 165 | 266 | 156 | **893** | 1282 | N/A | +| RETURNS | 7176 | 6121 | 3517 | **4474** | 7528 | N/A | +| WATER | 42268 | 4413 | 5266 | **5106** | 5289 | N/A | +| - | - | - | - | - | - | | +| Total | 42269 | 6556 | 5266 | **5106** | 7529 | 7457 | diff --git a/app/services/data/tear-down/crm-schema.service.js b/app/services/data/tear-down/crm-schema.service.js index 5266d13060..365c0f2221 100644 --- a/app/services/data/tear-down/crm-schema.service.js +++ b/app/services/data/tear-down/crm-schema.service.js @@ -8,79 +8,216 @@ const { db } = require('../../../../db/db.js') async function go () { - await _deleteTestData('crm_v2.documentRoles') - await _deleteTestData('crm_v2.companyAddresses') - await _deleteEntities() - await _deleteInvoiceAccounts() - await _deleteTestData('crm_v2.companyContacts') - await _deleteTestData('crm_v2.companies') - await _deleteTestData('crm_v2.addresses') - await _deleteDocuments() - await _deleteTestData('crm_v2.contacts') - - await _deleteCompanies() + return Promise.all([ + _crmEntityRoles(), + _crmEntity(), + _crmDocumentHeader(), + _crmV2DocumentRoles(), + _crmV2CompanyAddresses(), + _crmV2InvoiceAccountAddresses(), + _crmV2InvoiceAccounts(), + _crmV2CompanyContacts(), + _crmV2Companies(), + _crmV2Addresses(), + _crmV2Documents(), + _crmV2Contacts() + ]) } -async function _deleteCompanies () { - await db - .from('crm_v2.companies') - .whereLike('name', 'Big Farm Co Ltd%') - .del() +async function _crmEntityRoles () { + return db.raw(` + DELETE + FROM + crm.entity_roles + WHERE + created_by = 'acceptance-test-setup'; + `) } -async function _deleteEntities () { - await db - .from('crm.entityRoles') - .where('createdBy', 'acceptance-test-setup') - .del() - - await db - .from('crm.entity') - .whereLike('entityNm', 'acceptance-test.%') - .orWhereLike('entityNm', '%@example.com') - .orWhereLike('entityNm', 'regression.tests.%') - .orWhereLike('entityNm', 'Big Farm Co Ltd%') - .orWhere('source', 'acceptance-test-setup') - .del() +async function _crmEntity () { + return db.raw(` + DELETE + FROM + crm.entity + WHERE + entity_nm LIKE 'acceptance-test.%' + OR entity_nm LIKE '%@example.com' + OR entity_nm LIKE 'regression.tests.%' + OR entity_nm LIKE 'Big Farm Co Ltd%' + OR SOURCE = 'acceptance-test-setup'; + `) } -async function _deleteInvoiceAccounts () { - await db - .from('crm_v2.invoiceAccountAddresses as iaa') - .innerJoin('crm_v2.invoiceAccounts as ia', 'iaa.invoiceAccountId', 'ia.invoiceAccountId') - .innerJoin('crm_v2.companies as c', 'ia.companyId', 'c.companyId') - .where('c.isTest', true) - .del() - - await _deleteTestData('crm_v2.invoiceAccountAddresses') - - await db - .from('crm_v2.invoiceAccounts as ia') - .innerJoin('crm_v2.companies as c', 'ia.companyId', 'c.companyId') - .where('c.isTest', true) - .del() +async function _crmDocumentHeader () { + return db.raw(` + ALTER TABLE crm.document_header DISABLE TRIGGER ALL; + + DELETE + FROM + crm.document_header + WHERE + jsonb_path_query_first( + metadata, + '$.dataType' + ) #>> '{}' = 'acceptance-test-setup'; + + ALTER TABLE crm.document_header ENABLE TRIGGER ALL; + `) +} + +async function _crmV2DocumentRoles () { + return db.raw(` + ALTER TABLE crm_v2.document_roles DISABLE TRIGGER ALL; + + DELETE + FROM + "crm_v2"."document_roles" + WHERE + "is_test" = TRUE; + + ALTER TABLE crm_v2.document_roles ENABLE TRIGGER ALL; + `) +} + +async function _crmV2CompanyAddresses () { + return db.raw(` + ALTER TABLE crm_v2.company_addresses DISABLE TRIGGER ALL; + + DELETE + FROM + "crm_v2"."company_addresses" + WHERE + "is_test" = TRUE; + + ALTER TABLE crm_v2.company_addresses ENABLE TRIGGER ALL; + `) } -async function _deleteDocuments () { - await _deleteTestData('crm_v2.documents') +async function _crmV2InvoiceAccountAddresses () { + return db.raw(` + ALTER TABLE crm_v2.invoice_account_addresses DISABLE TRIGGER ALL; + + DELETE + FROM + "crm_v2"."invoice_account_addresses" AS "iaa" + USING "crm_v2"."invoice_accounts" AS "ia", + "crm_v2"."companies" AS "c" + WHERE + "c"."is_test" = TRUE + AND "iaa"."invoice_account_id" = "ia"."invoice_account_id" + AND "ia"."company_id" = "c"."company_id"; - await db - .from('crm_v2.documents as d') - .innerJoin('crm.documentHeader as dh', 'd.documentRef', 'dh.systemExternalId') - .whereJsonPath('dh.metadata', '$.dataType', '=', 'acceptance-test-setup') - .del() + DELETE + FROM + "crm_v2"."invoice_account_addresses" + WHERE + "is_test" = TRUE; - await db - .from('crm.documentHeader') - .whereJsonPath('metadata', '$.dataType', '=', 'acceptance-test-setup') - .del() + ALTER TABLE crm_v2.invoice_account_addresses ENABLE TRIGGER ALL; + `) } -async function _deleteTestData (tableName) { - await db - .from(tableName) - .where('isTest', true) - .del() +async function _crmV2InvoiceAccounts () { + return db.raw(` + ALTER TABLE crm_v2.invoice_accounts DISABLE TRIGGER ALL; + + DELETE + FROM + "crm_v2"."invoice_accounts" AS "ia" + USING "crm_v2"."companies" AS "c" + WHERE + "c"."is_test" = TRUE + AND "ia"."company_id" = "c"."company_id"; + + ALTER TABLE crm_v2.invoice_accounts ENABLE TRIGGER ALL; + `) +} + +async function _crmV2CompanyContacts () { + return db.raw(` + ALTER TABLE crm_v2.company_contacts DISABLE TRIGGER ALL; + + DELETE + FROM + "crm_v2"."company_contacts" + WHERE + "is_test" = TRUE; + + ALTER TABLE crm_v2.company_contacts ENABLE TRIGGER ALL; + `) +} + +async function _crmV2Companies () { + return db.raw(` + ALTER TABLE crm_v2.companies DISABLE TRIGGER ALL; + + DELETE + FROM + "crm_v2"."companies" + WHERE + "is_test" = TRUE; + + DELETE + FROM + "crm_v2"."companies" + WHERE + "name" LIKE 'Big Farm Co Ltd%'; + + ALTER TABLE crm_v2.companies ENABLE TRIGGER ALL; + `) +} + +async function _crmV2Addresses () { + return db.raw(` + ALTER TABLE crm_v2.addresses DISABLE TRIGGER ALL; + + DELETE + FROM + "crm_v2"."addresses" + WHERE + "is_test" = TRUE; + + ALTER TABLE crm_v2.addresses ENABLE TRIGGER ALL; + `) +} + +async function _crmV2Documents () { + return db.raw(` + ALTER TABLE crm_v2.documents DISABLE TRIGGER ALL; + + DELETE + FROM + "crm_v2"."documents" + WHERE + "is_test" = TRUE; + + DELETE + FROM + "crm_v2"."documents" AS "d" + USING "crm"."document_header" AS "dh" + WHERE + jsonb_path_query_first( + "dh"."metadata", + '$.dataType' + ) #>> '{}' = 'acceptance-test-setup' + AND "d"."document_ref" = "dh"."system_external_id"; + + ALTER TABLE crm_v2.documents ENABLE TRIGGER ALL; + `) +} + +async function _crmV2Contacts () { + return db.raw(` + ALTER TABLE crm_v2.contacts DISABLE TRIGGER ALL; + + DELETE + FROM + "crm_v2"."contacts" + WHERE + "is_test" = TRUE; + + ALTER TABLE crm_v2.contacts ENABLE TRIGGER ALL; + `) } module.exports = { diff --git a/app/services/data/tear-down/idm-schema.service.js b/app/services/data/tear-down/idm-schema.service.js index 99f7692e24..77e471db8f 100644 --- a/app/services/data/tear-down/idm-schema.service.js +++ b/app/services/data/tear-down/idm-schema.service.js @@ -8,11 +8,21 @@ const { db } = require('../../../../db/db.js') async function go () { - await db - .from('idm.users') - .whereJsonPath('user_data', '$.source', '=', 'acceptance-test-setup') - .orWhereLike('userName', '%@example.com') - .del() + return _users() +} + +async function _users () { + return db.raw(` + DELETE + FROM + "idm"."users" + WHERE + jsonb_path_query_first( + "user_data", + '$.source' + ) #>> '{}' = 'acceptance-test-setup' + OR "user_name" LIKE '%@example.com'; + `) } module.exports = { diff --git a/app/services/data/tear-down/permit-schema.service.js b/app/services/data/tear-down/permit-schema.service.js index 011e3ad595..3d0ba6ca12 100644 --- a/app/services/data/tear-down/permit-schema.service.js +++ b/app/services/data/tear-down/permit-schema.service.js @@ -8,10 +8,24 @@ const { db } = require('../../../../db/db.js') async function go () { - await db - .from('permit.licence') - .whereJsonPath('metadata', '$.source', '=', 'acceptance-test-setup') - .del() + return _licence() +} + +async function _licence () { + return db.raw(` + ALTER TABLE permit.licence DISABLE TRIGGER ALL; + + DELETE + FROM + "permit"."licence" + WHERE + jsonb_path_query_first( + "metadata", + '$.source' + ) #>> '{}' = 'acceptance-test-setup'; + + ALTER TABLE permit.licence ENABLE TRIGGER ALL; + `) } module.exports = { diff --git a/app/services/data/tear-down/returns-schema.service.js b/app/services/data/tear-down/returns-schema.service.js index b2bc3f9ae5..bfeee430e7 100644 --- a/app/services/data/tear-down/returns-schema.service.js +++ b/app/services/data/tear-down/returns-schema.service.js @@ -8,23 +8,59 @@ const { db } = require('../../../../db/db.js') async function go () { - await db - .from('returns.lines as l') - .innerJoin('returns.versions as v', 'l.versionId', 'v.versionId') - .innerJoin('returns.returns as r', 'v.returnId', 'r.returnId') - .where('r.isTest', true) - .del() - - await db - .from('returns.versions as v') - .innerJoin('returns.returns as r', 'v.returnId', 'r.returnId') - .where('r.isTest', true) - .del() - - await db - .from('returns.returns') - .where('isTest', true) - .del() + return Promise.all([ + _lines(), + _versions(), + _returns() + ]) +} + +async function _lines () { + return db.raw(` + ALTER TABLE returns.lines DISABLE TRIGGER ALL; + + DELETE + FROM + "returns"."lines" AS "l" + USING "returns"."versions" AS "v", + "returns"."returns" AS "r" + WHERE + "r"."is_test" = TRUE + AND "l"."version_id" = "v"."version_id" + AND "v"."return_id" = "r"."return_id"; + + ALTER TABLE returns.lines ENABLE TRIGGER ALL; + `) +} + +async function _versions () { + return db.raw(` + ALTER TABLE returns.versions DISABLE TRIGGER ALL; + + DELETE + FROM + "returns"."versions" AS "v" + USING "returns"."returns" AS "r" + WHERE + "r"."is_test" = TRUE + AND "v"."return_id" = "r"."return_id"; + + ALTER TABLE returns.versions ENABLE TRIGGER ALL; + `) +} + +async function _returns () { + await db.raw(` + ALTER TABLE returns.returns DISABLE TRIGGER ALL; + + DELETE + FROM + "returns"."returns" + WHERE + "is_test" = TRUE; + + ALTER TABLE returns.returns ENABLE TRIGGER ALL; + `) } module.exports = { diff --git a/app/services/data/tear-down/water-schema.service.js b/app/services/data/tear-down/water-schema.service.js index c4695626c2..1405658e85 100644 --- a/app/services/data/tear-down/water-schema.service.js +++ b/app/services/data/tear-down/water-schema.service.js @@ -8,170 +8,417 @@ const { db } = require('../../../../db/db.js') async function go () { - await _deleteBilling() - await _deleteGaugingStations() - await _deleteTestData('water.chargeElements') - await _deleteChargeVersions() - await _deleteTestData('water.licenceAgreements') - await _deleteReturnRequirements() - await _deleteLicenceAgreements() - await _deleteTestData('water.financialAgreementTypes') - await _deleteTestData('water.licenceVersionPurposes') - await _deleteTestData('water.licenceVersions') - await _deleteTestData('water.licences') - await _deleteTestData('water.regions') - await _deleteTestData('water.purposesPrimary') - await _deleteTestData('water.purposesSecondary') - await _deleteTestData('water.purposesUses') - await _deleteNotifications() - await _deleteSessions() -} - -async function _deleteBilling () { - const billLicences = await db - .from('water.billingTransactions as bt') - .innerJoin('water.billingInvoiceLicences as bil', 'bt.billingInvoiceLicenceId', 'bil.billingInvoiceLicenceId') - .innerJoin('water.billingInvoices as bi', 'bil.billingInvoiceId', 'bi.billingInvoiceId') - .innerJoin('water.billingBatches as bb', 'bi.billingBatchId', 'bb.billingBatchId') - .innerJoin('water.regions as r', 'bb.regionId', 'r.regionId') - .where('r.isTest', true) - .del(['bt.billingInvoiceLicenceId']) - - const billLicenceIds = billLicences.map((billLicence) => { - return billLicence.billingInvoiceLicenceId - }) - - const bills = await db - .from('water.billingInvoiceLicences') - .whereIn('billingInvoiceLicenceId', billLicenceIds) - .del(['billingInvoiceId']) - - const billIds = bills.map((bill) => { - return bill.billingInvoiceId - }) - - const billRuns = await db - .from('water.billingInvoices') - .whereIn('billingInvoiceId', billIds) - .del(['billingBatchId']) - - const billRunIds = billRuns.map((billRun) => { - return billRun.billingBatchId - }) - - await db - .from('water.billingBatchChargeVersionYears') - .whereIn('billingBatchId', billRunIds) - .del() - - await db - .from('water.billingVolumes') - .whereIn('billingBatchId', billRunIds) - .del() - - // Just deleting the `billingBatches` based on the `billingBatchIds` does not always remove all test records so the - // Test Region is used to identify the records for deletion - await db - .from('water.billingBatches as bb') - .innerJoin('water.regions as r', 'bb.regionId', 'r.regionId') - .where('r.isTest', true) - .del() -} - -async function _deleteGaugingStations () { - await db - .from('water.licenceGaugingStations as lgs') - .innerJoin('water.gaugingStations as gs', 'lgs.gaugingStationId', 'gs.gaugingStationId') - .where('gs.isTest', true) - .del() - - await _deleteTestData('water.gaugingStations') -} - -async function _deleteChargeVersions () { - await db - .from('water.chargeVersionWorkflows') - .del() - - await db - .from('water.chargeElements as ce') - .innerJoin('water.chargeVersions as cv', 'ce.chargeVersionId', 'cv.chargeVersionId') - .innerJoin('water.licences as l', 'cv.licenceId', 'l.licenceId') - .where('l.isTest', true) - .del() - - await db - .from('water.chargeVersions as cv') - .innerJoin('water.licences as l', 'cv.licenceId', 'l.licenceId') - .where('l.isTest', true) - .del() -} - -async function _deleteReturnRequirements () { - await db - .from('water.returnRequirementPurposes as rrp') - .innerJoin('water.returnRequirements as rr', 'rrp.returnRequirementId', 'rr.returnRequirementId') - .innerJoin('water.returnVersions as rv', 'rr.returnVersionId', 'rv.returnVersionId') - .innerJoin('water.licences as l', 'rv.licenceId', 'l.licenceId') - .where('l.isTest', true) - .del() - - await db - .from('water.returnRequirements as rr') - .innerJoin('water.returnVersions as rv', 'rr.returnVersionId', 'rv.returnVersionId') - .innerJoin('water.licences as l', 'rv.licenceId', 'l.licenceId') - .where('l.isTest', true) - .del() - - await db - .from('water.returnVersions as rv') - .innerJoin('water.licences as l', 'rv.licenceId', 'l.licenceId') - .where('l.isTest', true) - .del() -} - -async function _deleteLicenceAgreements () { - await db - .from('water.licenceAgreements as la') - .innerJoin('water.licences as l', 'la.licenceRef', 'l.licenceRef') - .where('l.isTest', true) - .del() - - await _deleteTestData('water.licenceAgreements') -} - -async function _deleteNotifications () { - await db - .from('water.scheduledNotification') - .where('messageRef', 'test-ref') - .del() - - await db - .from('water.scheduledNotification as sn') - .innerJoin('water.events as e', 'sn.eventId', 'e.eventId') - .whereLike('e.issuer', 'acceptance-test%') - .del() - - await db - .from('water.events') - .whereLike('issuer', 'acceptance-test%') - .del() -} - -async function _deleteSessions () { - await db - .from('water.sessions') - // NOTE: Normally we would use whereJsonPath() when working with JSONB fields in PostgreSQL. However, the previous - // team opted to create 'session_data' as a varchar field and dump JSON into it. So, we are unable to in this case. - .where(db.raw("session_data::jsonb->>'companyName' = 'acceptance-test-company'")) - .del() -} - -async function _deleteTestData (tableName) { - await db - .from(tableName) - .where('isTest', true) - .del() + await Promise.all([ + _billingTransactions(), + _billingInvoiceLicences(), + _billingInvoices(), + _billingChargeVersionYears(), + _billingVolumes(), + _billingBatches(), + _gaugingStations(), + _chargeElements(), + _chargeVersionWorkflows(), + _chargeVersions(), + _licenceAgreements(), + _returnRequirementPurposes(), + _returnRequirements(), + _returnVersions(), + _financialAgreementTypes(), + _licenceVersionPurposes(), + _licenceVersions(), + _licences(), + _purposesPrimary, + _purposesSecondary(), + _purposesUses(), + _scheduledNotification(), + _events(), + _sessions() + ]) + + return _regions() +} + +async function _billingTransactions () { + return db.raw(` + ALTER TABLE water.billing_transactions DISABLE TRIGGER ALL; + + DELETE + FROM + "water"."billing_transactions" AS "bt" + USING "water"."billing_invoice_licences" AS "bil", + "water"."billing_invoices" AS "bi", + "water"."billing_batches" AS "bb", + "water"."regions" AS "r" + WHERE + "r"."is_test" = TRUE + AND "bt"."billing_invoice_licence_id" = "bil"."billing_invoice_licence_id" + AND "bil"."billing_invoice_id" = "bi"."billing_invoice_id" + AND "bi"."billing_batch_id" = "bb"."billing_batch_id" + AND "bb"."region_id" = "r"."region_id"; + + ALTER TABLE water.billing_transactions ENABLE TRIGGER ALL; + `) +} + +async function _billingInvoiceLicences () { + return db.raw(` + ALTER TABLE water.billing_invoice_licences DISABLE TRIGGER ALL; + + DELETE + FROM + "water"."billing_invoice_licences" AS "bil" + USING "water"."billing_invoices" AS "bi", + "water"."billing_batches" AS "bb", + "water"."regions" AS "r" + WHERE + "r"."is_test" = TRUE + AND "bil"."billing_invoice_id" = "bi"."billing_invoice_id" + AND "bi"."billing_batch_id" = "bb"."billing_batch_id" + AND "bb"."region_id" = "r"."region_id"; + + ALTER TABLE water.billing_invoice_licences ENABLE TRIGGER ALL; + `) +} + +async function _billingInvoices () { + return db.raw(` + ALTER TABLE water.billing_invoices DISABLE TRIGGER ALL; + + DELETE + FROM + "water"."billing_invoices" AS "bi" + USING "water"."billing_batches" AS "bb", + "water"."regions" AS "r" + WHERE + "r"."is_test" = TRUE + AND "bi"."billing_batch_id" = "bb"."billing_batch_id" + AND "bb"."region_id" = "r"."region_id"; + + ALTER TABLE water.billing_invoices ENABLE TRIGGER ALL; + `) +} + +async function _billingChargeVersionYears () { + return db.raw(` + ALTER TABLE water.billing_batch_charge_version_years DISABLE TRIGGER ALL; + + DELETE + FROM + "water"."billing_batch_charge_version_years" AS "bbcvy" + USING "water"."billing_batches" AS "bb", + "water"."regions" AS "r" + WHERE + "r"."is_test" = TRUE + AND "bbcvy"."billing_batch_id" = "bb"."billing_batch_id" + AND "bb"."region_id" = "r"."region_id"; + + ALTER TABLE water.billing_batch_charge_version_years ENABLE TRIGGER ALL; + `) +} + +async function _billingVolumes () { + return db.raw(` + ALTER TABLE water.billing_volumes DISABLE TRIGGER ALL; + + DELETE + FROM + "water"."billing_volumes" AS "bv" + USING "water"."billing_batches" AS "bb", + "water"."regions" AS "r" + WHERE + "r"."is_test" = TRUE + AND "bv"."billing_batch_id" = "bb"."billing_batch_id" + AND "bb"."region_id" = "r"."region_id"; + + ALTER TABLE water.billing_volumes ENABLE TRIGGER ALL; + `) +} + +async function _billingBatches () { + return db.raw(` + ALTER TABLE water.billing_batches DISABLE TRIGGER ALL; + + DELETE + FROM + "water"."billing_batches" AS "bb" + USING "water"."regions" AS "r" + WHERE + "r"."is_test" = TRUE + AND "bb"."region_id" = "r"."region_id"; + + ALTER TABLE water.billing_batches ENABLE TRIGGER ALL; + `) +} + +async function _gaugingStations () { + return db.raw(` + DELETE + FROM + "water"."licence_gauging_stations" AS "lgs" + USING "water"."gauging_stations" AS "gs" + WHERE + "gs"."is_test" = TRUE + AND "lgs"."gauging_station_id" = "gs"."gauging_station_id"; + + DELETE + FROM + "water"."gauging_stations" + WHERE + "is_test" = TRUE; + `) +} + +async function _chargeElements () { + return db.raw(` + ALTER TABLE water.charge_elements DISABLE TRIGGER ALL; + + DELETE + FROM + "water"."charge_elements" + WHERE + "is_test" = TRUE; + + DELETE + FROM + "water"."charge_elements" AS "ce" + USING "water"."charge_versions" AS "cv", + "water"."licences" AS "l" + WHERE + "l"."is_test" = TRUE + AND "ce"."charge_version_id" = "cv"."charge_version_id" + AND "cv"."licence_id" = "l"."licence_id"; + + ALTER TABLE water.charge_elements ENABLE TRIGGER ALL; + `) +} + +async function _chargeVersionWorkflows () { + return db.raw(` + ALTER TABLE water.charge_version_workflows DISABLE TRIGGER ALL; + + TRUNCATE + "water"."charge_version_workflows"; + + ALTER TABLE water.charge_version_workflows ENABLE TRIGGER ALL; + `) +} + +async function _chargeVersions () { + return db.raw(` + ALTER TABLE water.charge_versions DISABLE TRIGGER ALL; + + DELETE + FROM + "water"."charge_versions" AS "cv" + USING "water"."licences" AS "l" + WHERE + "l"."is_test" = TRUE + AND "cv"."licence_id" = "l"."licence_id"; + + ALTER TABLE water.charge_versions ENABLE TRIGGER ALL; + `) +} + +async function _licenceAgreements () { + return db.raw(` + ALTER TABLE water.licence_agreements DISABLE TRIGGER ALL; + + DELETE + FROM + "water"."licence_agreements" + WHERE + "is_test" = TRUE; + + ALTER TABLE water.licence_agreements ENABLE TRIGGER ALL; + `) +} + +async function _returnRequirementPurposes () { + return db.raw(` + ALTER TABLE water.return_requirement_purposes DISABLE TRIGGER ALL; + + DELETE + FROM + "water"."return_requirement_purposes" AS "rrp" + USING "water"."return_requirements" AS "rr", + "water"."return_versions" AS "rv", + "water"."licences" AS "l" + WHERE + "l"."is_test" = TRUE + AND "rrp"."return_requirement_id" = "rr"."return_requirement_id" + AND "rr"."return_version_id" = "rv"."return_version_id" + AND "rv"."licence_id" = "l"."licence_id"; + + ALTER TABLE water.return_requirement_purposes ENABLE TRIGGER ALL; + `) +} + +async function _returnRequirements () { + return db.raw(` + ALTER TABLE water.return_requirements DISABLE TRIGGER ALL; + + DELETE + FROM + "water"."return_requirements" AS "rr" + USING "water"."return_versions" AS "rv", + "water"."licences" AS "l" + WHERE + "l"."is_test" = TRUE + AND "rr"."return_version_id" = "rv"."return_version_id" + AND "rv"."licence_id" = "l"."licence_id"; + + ALTER TABLE water.return_requirements ENABLE TRIGGER ALL; + `) +} + +async function _returnVersions () { + return db.raw(` + ALTER TABLE water.return_versions DISABLE TRIGGER ALL; + + DELETE + FROM + "water"."return_versions" AS "rv" + USING "water"."licences" AS "l" + WHERE + "l"."is_test" = TRUE + AND "rv"."licence_id" = "l"."licence_id"; + + ALTER TABLE water.return_versions ENABLE TRIGGER ALL; + `) +} + +async function _financialAgreementTypes () { + return db.raw(` + DELETE + FROM + "water"."financial_agreement_types" + WHERE + "is_test" = TRUE; + `) +} + +async function _licenceVersionPurposes () { + return db.raw(` + ALTER TABLE water.licence_version_purposes DISABLE TRIGGER ALL; + + DELETE + FROM + "water"."licence_version_purposes" + WHERE + "is_test" = TRUE; + + ALTER TABLE water.licence_version_purposes ENABLE TRIGGER ALL; + `) +} + +async function _licenceVersions () { + return db.raw(` + ALTER TABLE water.licence_versions DISABLE TRIGGER ALL; + + DELETE + FROM + "water"."licence_versions" + WHERE + "is_test" = TRUE; + + ALTER TABLE water.licence_versions ENABLE TRIGGER ALL; + `) +} + +async function _licences () { + return db.raw(` + ALTER TABLE water.licences DISABLE TRIGGER ALL; + + DELETE + FROM + "water"."licences" + WHERE + "is_test" = TRUE; + + ALTER TABLE water.licences ENABLE TRIGGER ALL; + `) +} + +async function _regions () { + return db.raw(` + DELETE + FROM + "water"."regions" + WHERE + "is_test" = TRUE; + `) +} + +async function _purposesPrimary () { + return db.raw(` + DELETE + FROM + "water"."purposes_primary" + WHERE + "is_test" = TRUE; + `) +} + +async function _purposesSecondary () { + return db.raw(` + DELETE + FROM + "water"."purposes_secondary" + WHERE + "is_test" = TRUE; + `) +} + +async function _purposesUses () { + return db.raw(` + DELETE + FROM + "water"."purposes_uses" + WHERE + "is_test" = TRUE; + `) +} + +async function _scheduledNotification () { + return db.raw(` + ALTER TABLE water.scheduled_notification DISABLE TRIGGER ALL; + + DELETE + FROM + "water"."scheduled_notification" + WHERE + "message_ref" = 'test-ref'; + + DELETE + FROM + "water"."scheduled_notification" AS "sn" + USING "water"."events" AS "e" + WHERE + "e"."issuer" LIKE 'acceptance-test%' + AND "sn"."event_id" = "e"."event_id"; + + ALTER TABLE water.scheduled_notification ENABLE TRIGGER ALL; + `) +} + +async function _events () { + return db.raw(` + DELETE + FROM + "water"."events" + WHERE + "issuer" LIKE 'acceptance-test%'; + `) +} + +async function _sessions () { + return db.raw(` + DELETE + FROM + "water"."sessions" + WHERE + session_data::jsonb->>'companyName' = 'acceptance-test-company'; + `) } module.exports = {