From 5439c4fbc67b29863ea583c6cff38ca9d049b011 Mon Sep 17 00:00:00 2001 From: sambokar Date: Fri, 11 Oct 2024 10:56:58 -0400 Subject: [PATCH] emergency hotfix -- migration and handling system was not correctly accounting for many-to-many relationship between quadrats and census, thus losing extensive historical data. system reworked and repaired to 1) incorporate censusquadrat table, 2) clean sql scripts and rework migration system & table structures to properly handle censusquadrat table, 3) rework all relevant API endpoints to correctly reference censusquadrat table, and 4) rework fixeddata PATCH/POST/DELETE to handle interactions with censusquadrat along with processor files --- .../[dataType]/[[...slugs]]/route.ts | 42 +- .../app/api/fetchall/[[...slugs]]/route.ts | 6 + .../[dataType]/[[...slugs]]/route.ts | 54 +- .../rollover/[dataType]/[[...slugs]]/route.ts | 22 +- .../isolated/isolatedquadratsdatagrid.tsx | 1 - .../applications/quadratsdatagrid.tsx | 1 - .../datagrids/isolateddatagridcommons.tsx | 5 +- .../components/processors/processcensus.tsx | 8 +- .../components/processors/processormacros.tsx | 1 - frontend/config/datagridhelpers.ts | 14 +- frontend/config/sqlrdsdefinitions/zones.ts | 1 - .../sqlscripting/corevalidationprocedures.sql | 1476 --------- frontend/sqlscripting/coverageindexes.sql | 86 - frontend/sqlscripting/drop_all_triggers.sql | 230 -- .../internalvalidationskeleton.sql | 101 - .../materializedviewrefreshprocedures.sql | 104 - .../materializedviews/fulltriggers.sql | 427 --- .../measurementssummary/refresh.sql | 39 - .../measurementssummary/table.sql | 104 - .../viewfulltable/refresh.sql | 169 - .../materializedviews/viewfulltable/table.sql | 307 -- .../sqlscripting/materializedviewtriggers.sql | 427 --- .../migration-OoO/1-resetexistingschema.sql | 532 ---- .../2-clearchangelogtriggers.sql | 119 - .../3-clearmaterializedviewtriggers.sql | 85 - .../migration-OoO/4-migrationstatements.sql | 295 -- .../migration-OoO/5-recreatetriggers.sql | 1442 --------- .../migration-OoO/6-recreateviews.sql | 186 -- .../migration-OoO/7-recreateprocedures.sql | 2159 ------------- .../8-recreaterefreshtriggers.sql | 401 --- .../sqlscripting/migration_no_mapping.sql | 91 +- frontend/sqlscripting/migrationbackup.sql | 470 --- frontend/sqlscripting/resetautoincrements.sql | 165 - frontend/sqlscripting/resetschema.sql | 24 - frontend/sqlscripting/resettestingschema.sql | 2798 ----------------- frontend/sqlscripting/storedprocedures.sql | 46 - frontend/sqlscripting/tablestructures.sql | 83 +- frontend/sqlscripting/tempmigratechanges.sql | 6 - frontend/sqlscripting/triggers.sql | 43 +- frontend/sqlscripting/triggersbackup.sql | 2376 -------------- frontend/sqlscripting/undorollover.sql | 42 - frontend/sqlscripting/updatedviews.sql | 3 +- 42 files changed, 178 insertions(+), 14813 deletions(-) delete mode 100644 frontend/sqlscripting/corevalidationprocedures.sql delete mode 100644 frontend/sqlscripting/coverageindexes.sql delete mode 100644 frontend/sqlscripting/drop_all_triggers.sql delete mode 100644 frontend/sqlscripting/internalvalidationskeleton.sql delete mode 100644 frontend/sqlscripting/materializedviewrefreshprocedures.sql delete mode 100644 frontend/sqlscripting/materializedviews/fulltriggers.sql delete mode 100644 frontend/sqlscripting/materializedviews/measurementssummary/refresh.sql delete mode 100644 frontend/sqlscripting/materializedviews/measurementssummary/table.sql delete mode 100644 frontend/sqlscripting/materializedviews/viewfulltable/refresh.sql delete mode 100644 frontend/sqlscripting/materializedviews/viewfulltable/table.sql delete mode 100644 frontend/sqlscripting/materializedviewtriggers.sql delete mode 100644 frontend/sqlscripting/migration-OoO/1-resetexistingschema.sql delete mode 100644 frontend/sqlscripting/migration-OoO/2-clearchangelogtriggers.sql delete mode 100644 frontend/sqlscripting/migration-OoO/3-clearmaterializedviewtriggers.sql delete mode 100644 frontend/sqlscripting/migration-OoO/4-migrationstatements.sql delete mode 100644 frontend/sqlscripting/migration-OoO/5-recreatetriggers.sql delete mode 100644 frontend/sqlscripting/migration-OoO/6-recreateviews.sql delete mode 100644 frontend/sqlscripting/migration-OoO/7-recreateprocedures.sql delete mode 100644 frontend/sqlscripting/migration-OoO/8-recreaterefreshtriggers.sql delete mode 100644 frontend/sqlscripting/migrationbackup.sql delete mode 100644 frontend/sqlscripting/resetautoincrements.sql delete mode 100644 frontend/sqlscripting/resetschema.sql delete mode 100644 frontend/sqlscripting/resettestingschema.sql delete mode 100644 frontend/sqlscripting/tempmigratechanges.sql delete mode 100644 frontend/sqlscripting/triggersbackup.sql delete mode 100644 frontend/sqlscripting/undorollover.sql diff --git a/frontend/app/api/cmprevalidation/[dataType]/[[...slugs]]/route.ts b/frontend/app/api/cmprevalidation/[dataType]/[[...slugs]]/route.ts index 0685afff..23a2f19f 100644 --- a/frontend/app/api/cmprevalidation/[dataType]/[[...slugs]]/route.ts +++ b/frontend/app/api/cmprevalidation/[dataType]/[[...slugs]]/route.ts @@ -36,7 +36,7 @@ export async function GET(_request: NextRequest, { params }: { params: { dataTyp }); break; case 'personnel': - const pQuery = `SELECT 1 FROM ${schema}.${params.dataType} WHERE CensusID IN (SELECT CensusID from ${schema}.census WHERE PlotID = ${plotID} AND PlotCensusNumber = ${plotCensusNumber})`; // Check if the table has any row + const pQuery = `SELECT 1 FROM ${schema}.personnel WHERE CensusID IN (SELECT CensusID from ${schema}.census WHERE PlotID = ${plotID} AND PlotCensusNumber = ${plotCensusNumber})`; // Check if the table has any row const pResults = await runQuery(connection, pQuery); if (connection) connection.release(); if (pResults.length === 0) @@ -45,7 +45,10 @@ export async function GET(_request: NextRequest, { params }: { params: { dataTyp }); break; case 'quadrats': - const query = `SELECT 1 FROM ${schema}.${params.dataType} WHERE PlotID = ${plotID} AND CensusID IN (SELECT CensusID from ${schema}.census WHERE PlotID = ${plotID} AND PlotCensusNumber = ${plotCensusNumber})`; // Check if the table has any row + const query = `SELECT 1 FROM ${schema}.quadrats q + JOIN ${schema}.censusquadrat cq ON cq.QuadratID = q.QuadratID + JOIN ${schema}.census c ON cq.CensusID = c.CensusID + WHERE q.PlotID = ${plotID} AND c.PlotCensusNumber = ${plotCensusNumber} LIMIT 1`; const results = await runQuery(connection, query); if (connection) connection.release(); if (results.length === 0) @@ -53,25 +56,28 @@ export async function GET(_request: NextRequest, { params }: { params: { dataTyp status: HTTPResponses.PRECONDITION_VALIDATION_FAILURE }); break; - case 'subquadrats': - const subquadratsQuery = `SELECT 1 - FROM ${schema}.${params.dataType} s - JOIN ${schema}.quadrats q ON s.QuadratID = q.QuadratID - WHERE q.PlotID = ${plotID} - AND q.CensusID IN (SELECT CensusID from ${schema}.census WHERE PlotID = ${plotID} AND PlotCensusNumber = ${plotCensusNumber}) LIMIT 1`; - const subquadratsResults = await runQuery(connection, subquadratsQuery); - if (connection) connection.release(); - if (subquadratsResults.length === 0) - return new NextResponse(null, { - status: HTTPResponses.PRECONDITION_VALIDATION_FAILURE - }); - break; + // case 'subquadrats': + // const subquadratsQuery = `SELECT 1 + // FROM ${schema}.${params.dataType} s + // JOIN ${schema}.quadrats q ON s.QuadratID = q.QuadratID + // WHERE q.PlotID = ${plotID} + // AND q.CensusID IN (SELECT CensusID from ${schema}.census WHERE PlotID = ${plotID} AND PlotCensusNumber = ${plotCensusNumber}) LIMIT 1`; + // const subquadratsResults = await runQuery(connection, subquadratsQuery); + // if (connection) connection.release(); + // if (subquadratsResults.length === 0) + // return new NextResponse(null, { + // status: HTTPResponses.PRECONDITION_VALIDATION_FAILURE + // }); + // break; case 'quadratpersonnel': // Validation for quadrats table const quadratsQuery = `SELECT 1 - FROM ${schema}.quadrats - WHERE PlotID = ${plotID} - AND CensusID IN (SELECT CensusID from ${schema}.census WHERE PlotID = ${plotID} AND PlotCensusNumber = ${plotCensusNumber}) LIMIT 1`; + FROM ${schema}.quadrats q + JOIN ${schema}.censusquadrat cq on cq.QuadratID = q.QuadratID + JOIN ${schema}.census c on cq.CensusID = c.CensusID + JOIN ${schema}.personnel p ON p.CensusID = c.CensusID + WHERE q.PlotID = ${plotID} + AND c.PlotCensusNumber = ${plotCensusNumber} LIMIT 1`; const quadratsResults = await runQuery(connection, quadratsQuery); if (connection) connection.release(); if (quadratsResults.length === 0) diff --git a/frontend/app/api/fetchall/[[...slugs]]/route.ts b/frontend/app/api/fetchall/[[...slugs]]/route.ts index 9cd93c6f..42daf7c6 100644 --- a/frontend/app/api/fetchall/[[...slugs]]/route.ts +++ b/frontend/app/api/fetchall/[[...slugs]]/route.ts @@ -17,6 +17,12 @@ const buildQuery = (schema: string, fetchType: string, plotID?: string, plotCens } else if (fetchType === 'roles') { return `SELECT * FROM ${schema}.${fetchType}`; + } else if (fetchType === 'quadrats') { + return ` + SELECT * FROM ${schema}.quadrats q + JOIN ${schema}.censusquadrat cq ON cq.QuadratID = q.QuadratID + JOIN ${schema}.census c ON cq.CensusID = c.CensusID + WHERE q.PlotID = ${plotID} AND c.PlotID = ${plotID} AND c.PlotCensusNumber = ${plotCensusNumber}`; } else { let query = `SELECT * FROM ${schema}.${fetchType}`; diff --git a/frontend/app/api/fixeddata/[dataType]/[[...slugs]]/route.ts b/frontend/app/api/fixeddata/[dataType]/[[...slugs]]/route.ts index 6c9c03f3..f8cd1329 100644 --- a/frontend/app/api/fixeddata/[dataType]/[[...slugs]]/route.ts +++ b/frontend/app/api/fixeddata/[dataType]/[[...slugs]]/route.ts @@ -74,8 +74,9 @@ export async function GET( case 'quadrats': paginatedQuery = ` SELECT SQL_CALC_FOUND_ROWS q.* - FROM ${schema}.${params.dataType} q - JOIN ${schema}.census c ON q.PlotID = c.PlotID AND q.CensusID = c.CensusID + FROM ${schema}.quadrats q + JOIN ${schema}.censusquadrat cq ON q.QuadratID = cq.QuadratID + JOIN ${schema}.census c ON cq.CensusID = c.CensusID WHERE q.PlotID = ? AND c.PlotID = ? AND c.PlotCensusNumber = ? LIMIT ?, ?;`; @@ -112,21 +113,21 @@ export async function GET( ORDER BY q.MeasurementDate ASC LIMIT ?, ?;`; queryParams.push(plotID, plotID, plotCensusNumber, page * pageSize, pageSize); break; - case 'subquadrats': - if (!quadratID || quadratID === 0) { - throw new Error('QuadratID must be provided as part of slug fetch query, referenced fixeddata slug route'); - } - paginatedQuery = ` - SELECT SQL_CALC_FOUND_ROWS s.* - FROM ${schema}.subquadrats s - JOIN ${schema}.quadrats q ON s.QuadratID = q.QuadratID - JOIN ${schema}.census c ON q.CensusID = c.CensusID - WHERE q.QuadratID = ? - AND q.PlotID = ? - AND c.PlotID = ? - AND c.PlotCensusNumber = ? LIMIT ?, ?;`; - queryParams.push(quadratID, plotID, plotID, plotCensusNumber, page * pageSize, pageSize); - break; + // case 'subquadrats': + // if (!quadratID || quadratID === 0) { + // throw new Error('QuadratID must be provided as part of slug fetch query, referenced fixeddata slug route'); + // } + // paginatedQuery = ` + // SELECT SQL_CALC_FOUND_ROWS s.* + // FROM ${schema}.subquadrats s + // JOIN ${schema}.quadrats q ON s.QuadratID = q.QuadratID + // JOIN ${schema}.census c ON q.CensusID = c.CensusID + // WHERE q.QuadratID = ? + // AND q.PlotID = ? + // AND c.PlotID = ? + // AND c.PlotCensusNumber = ? LIMIT ?, ?;`; + // queryParams.push(quadratID, plotID, plotID, plotCensusNumber, page * pageSize, pageSize); + // break; case 'census': paginatedQuery = ` SELECT SQL_CALC_FOUND_ROWS * @@ -221,9 +222,12 @@ export async function GET( // required dynamic parameters: dataType (fixed),[ schema, gridID value] -> slugs export async function POST(request: NextRequest, { params }: { params: { dataType: string; slugs?: string[] } }) { if (!params.slugs) throw new Error('slugs not provided'); - const [schema, gridID] = params.slugs; + const [schema, gridID, plotIDParam, censusIDParam] = params.slugs; if (!schema || !gridID) throw new Error('no schema or gridID provided'); + const plotID = plotIDParam ? parseInt(plotIDParam) : undefined; + const censusID = censusIDParam ? parseInt(censusIDParam) : undefined; + let conn: PoolConnection | null = null; const { newRow } = await request.json(); let insertIDs: { [key: string]: number } = {}; @@ -254,14 +258,12 @@ export async function POST(request: NextRequest, { params }: { params: { dataTyp // Use handleUpsertForSlices and retrieve the insert IDs insertIDs = await handleUpsertForSlices(conn, schema, newRowData, queryConfig); } - // Handle the case for 'attributes' else if (params.dataType === 'attributes') { const insertQuery = format('INSERT INTO ?? SET ?', [`${schema}.${params.dataType}`, newRowData]); const results = await runQuery(conn, insertQuery); insertIDs = { attributes: results.insertId }; // Standardize output with table name as key } - // Handle all other cases else { delete newRowData[demappedGridID]; @@ -269,6 +271,13 @@ export async function POST(request: NextRequest, { params }: { params: { dataTyp const insertQuery = format('INSERT INTO ?? SET ?', [`${schema}.${params.dataType}`, newRowData]); const results = await runQuery(conn, insertQuery); insertIDs = { [params.dataType]: results.insertId }; // Standardize output with table name as key + + // special handling needed for quadrats --> need to correlate incoming quadrats with current census + if (params.dataType === 'quadrats' && censusID) { + const cqQuery = format('INSERT INTO ?? SET ?', [`${schema}.censusquadrats`, { CensusID: censusID, QuadratID: insertIDs.quadrats }]); + const results = await runQuery(conn, cqQuery); + if (results.length === 0) throw new Error('Error inserting to censusquadrats'); + } } // Commit the transaction and return the standardized response @@ -387,6 +396,11 @@ export async function DELETE(request: NextRequest, { params }: { params: { dataT // Handle deletion for tables const deleteRowData = MapperFactory.getMapper(params.dataType).demapData([newRow])[0]; const { [demappedGridID]: gridIDKey } = deleteRowData; + // for quadrats, censusquadrat needs to be cleared before quadrat can be deleted + if (params.dataType === 'quadrats') { + const qDeleteQuery = format(`DELETE FROM ?? WHERE ?? = ?`, [`${schema}.censusquadrat`, demappedGridID, gridIDKey]); + await runQuery(conn, qDeleteQuery); + } const deleteQuery = format(`DELETE FROM ?? WHERE ?? = ?`, [`${schema}.${params.dataType}`, demappedGridID, gridIDKey]); await runQuery(conn, deleteQuery); await conn.commit(); diff --git a/frontend/app/api/rollover/[dataType]/[[...slugs]]/route.ts b/frontend/app/api/rollover/[dataType]/[[...slugs]]/route.ts index 4737575d..4374cb07 100644 --- a/frontend/app/api/rollover/[dataType]/[[...slugs]]/route.ts +++ b/frontend/app/api/rollover/[dataType]/[[...slugs]]/route.ts @@ -32,23 +32,11 @@ export async function POST(request: NextRequest, { params }: { params: { dataTyp switch (params.dataType) { case 'quadrats': query = ` - INSERT INTO ${schema}.quadrats (PlotID, CensusID, QuadratName, StartX, StartY, CoordinateUnits, DimensionX, DimensionY, DimensionUnits, Area, AreaUnits, QuadratShape) - SELECT - PlotID, - ?, - QuadratName, - StartX, - StartY, - CoordinateUnits, - DimensionX, - DimensionY, - DimensionUnits, - Area, - AreaUnits, - QuadratShape - FROM ${schema}.quadrats - WHERE CensusID = ? AND QuadratID IN (${incoming.map(() => '?').join(', ')});`; - queryParams = [Number(newCensusID), Number(sourceCensusID), ...incoming]; + INSERT INTO censusquadrat (CensusID, QuadratID) + SELECT ?, q.QuadratID + FROM quadrats q + WHERE q.QuadratID IN (${incoming.map(() => '?').join(', ')});`; + queryParams = [Number(newCensusID), ...incoming]; await runQuery(conn, query, queryParams); break; case 'personnel': diff --git a/frontend/components/datagrids/applications/isolated/isolatedquadratsdatagrid.tsx b/frontend/components/datagrids/applications/isolated/isolatedquadratsdatagrid.tsx index 744ecc60..0181705a 100644 --- a/frontend/components/datagrids/applications/isolated/isolatedquadratsdatagrid.tsx +++ b/frontend/components/datagrids/applications/isolated/isolatedquadratsdatagrid.tsx @@ -18,7 +18,6 @@ export default function IsolatedQuadratsDataGrid() { id: 0, quadratID: 0, plotID: currentPlot?.plotID, - censusID: currentCensus?.dateRanges[0].censusID, quadratName: '', startX: 0, startY: 0, diff --git a/frontend/components/datagrids/applications/quadratsdatagrid.tsx b/frontend/components/datagrids/applications/quadratsdatagrid.tsx index 65072c42..6abe67b8 100644 --- a/frontend/components/datagrids/applications/quadratsdatagrid.tsx +++ b/frontend/components/datagrids/applications/quadratsdatagrid.tsx @@ -19,7 +19,6 @@ export default function QuadratsDataGrid() { id: 0, quadratID: 0, plotID: 0, - censusID: 0, quadratName: '', startX: 0, startY: 0, diff --git a/frontend/components/datagrids/isolateddatagridcommons.tsx b/frontend/components/datagrids/isolateddatagridcommons.tsx index 8d69bfa3..92859a5f 100644 --- a/frontend/components/datagrids/isolateddatagridcommons.tsx +++ b/frontend/components/datagrids/isolateddatagridcommons.tsx @@ -507,7 +507,10 @@ export default function IsolatedDataGridCommons(props: Readonly => { const gridID = getGridID(gridType); - const fetchProcessQuery = createPostPatchQuery(schemaName ?? '', gridType, gridID); + const fetchProcessQuery = + gridType !== 'quadrats' + ? createPostPatchQuery(schemaName ?? '', gridType, gridID) + : createPostPatchQuery(schemaName ?? '', gridType, gridID, currentPlot?.plotID, currentCensus?.dateRanges[0].censusID); try { const response = await fetch(fetchProcessQuery, { diff --git a/frontend/components/processors/processcensus.tsx b/frontend/components/processors/processcensus.tsx index 52e7f0c2..7ffccdbe 100644 --- a/frontend/components/processors/processcensus.tsx +++ b/frontend/components/processors/processcensus.tsx @@ -21,13 +21,7 @@ export async function processCensus(props: Readonly): Pr const speciesID = await fetchPrimaryKey(schema, 'species', { SpeciesCode: spcode }, connection, 'SpeciesID'); // Fetch quadrat - const quadratID = await fetchPrimaryKey( - schema, - 'quadrats', - { QuadratName: quadrat, PlotID: plotID, CensusID: censusID }, - connection, - 'QuadratID' - ); + const quadratID = await fetchPrimaryKey(schema, 'quadrats', { QuadratName: quadrat, PlotID: plotID }, connection, 'QuadratID'); if (tag) { // Handle Tree Upsert diff --git a/frontend/components/processors/processormacros.tsx b/frontend/components/processors/processormacros.tsx index b01f9938..f6c2ac98 100644 --- a/frontend/components/processors/processormacros.tsx +++ b/frontend/components/processors/processormacros.tsx @@ -64,7 +64,6 @@ export const fileMappings: Record = { columnMappings: { quadrat: 'QuadratName', plotID: 'PlotID', - censusID: 'CensusID', startx: 'StartX', starty: 'StartY', coordinateunit: 'CoordinateUnits', diff --git a/frontend/config/datagridhelpers.ts b/frontend/config/datagridhelpers.ts index a0da52f1..bfcf111a 100644 --- a/frontend/config/datagridhelpers.ts +++ b/frontend/config/datagridhelpers.ts @@ -43,7 +43,9 @@ export type ProcessPostPatchQueryFunction = ( // incorporated validation system into this too siteSchema: string, dataType: string, - gridID: string + gridID: string, + plotID?: number, + censusID?: number ) => string; export type ProcessDeletionQueryFunction = (siteSchema: string, dataType: string, gridID: string, deletionID: number | string) => string; @@ -93,8 +95,14 @@ const columnVisibilityMap: { [key: string]: { [key: string]: boolean } } = { export const getColumnVisibilityModel = (gridType: string): { [key: string]: boolean } => { return columnVisibilityMap[gridType] || columnVisibilityMap.default; }; -export const createPostPatchQuery: ProcessPostPatchQueryFunction = (siteSchema: string, dataType: string, gridID: string) => { - return `/api/fixeddata/${dataType}/${siteSchema}/${gridID}`; +export const createPostPatchQuery: ProcessPostPatchQueryFunction = ( + siteSchema: string, + dataType: string, + gridID: string, + plotID?: number, + censusID?: number +) => { + return `/api/fixeddata/${dataType}/${siteSchema}/${gridID}` + (plotID ? `/${plotID}` : '') + (censusID ? `/${censusID}` : ''); }; export const createFetchQuery: FetchQueryFunction = ( siteSchema: string, diff --git a/frontend/config/sqlrdsdefinitions/zones.ts b/frontend/config/sqlrdsdefinitions/zones.ts index 81d20eb9..fa28f769 100644 --- a/frontend/config/sqlrdsdefinitions/zones.ts +++ b/frontend/config/sqlrdsdefinitions/zones.ts @@ -76,7 +76,6 @@ export type QuadratRDS = { id?: number; quadratID?: number; plotID?: number; - censusID?: number; quadratName?: string; startX?: number; startY?: number; diff --git a/frontend/sqlscripting/corevalidationprocedures.sql b/frontend/sqlscripting/corevalidationprocedures.sql deleted file mode 100644 index 9379a25a..00000000 --- a/frontend/sqlscripting/corevalidationprocedures.sql +++ /dev/null @@ -1,1476 +0,0 @@ -create - definer = azureroot@`%` procedure ValidateDBHGrowthExceedsMax(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE vCoreMeasurementID INT; - DECLARE vPrevDBH DECIMAL(10, 2); - DECLARE vCurrDBH DECIMAL(10, 2); - DECLARE validationResult BIT; - DECLARE errorMessage VARCHAR(255); - DECLARE validationCriteria TEXT; - DECLARE measuredValue VARCHAR(255); - DECLARE expectedValueRange VARCHAR(255); - DECLARE additionalDetails TEXT; - DECLARE insertCount INT DEFAULT 0; - DECLARE expectedCount INT; - DECLARE successMessage VARCHAR(255); - DECLARE done INT DEFAULT FALSE; - DECLARE veID INT; - DECLARE cur CURSOR FOR - SELECT cm2.CoreMeasurementID, cm1.MeasuredDBH, cm2.MeasuredDBH - FROM coremeasurements cm1 - JOIN coremeasurements cm2 - ON cm1.StemID = cm2.StemID - AND YEAR(cm2.MeasurementDate) = YEAR(cm1.MeasurementDate) + 1 - LEFT JOIN stems st2 ON cm2.StemID = st2.StemID - LEFT JOIN quadrats q ON st2.QuadratID = q.QuadratID - LEFT JOIN cmattributes cma - ON cm1.CoreMeasurementID = cma.CoreMeasurementID - LEFT JOIN attributes a - ON cma.Code = a.Code - WHERE (a.Status NOT IN ('dead', 'stem dead', 'broken below', 'missing', 'omitted') OR a.Status IS NULL) - AND cm1.MeasuredDBH IS NOT NULL - AND cm2.MeasuredDBH IS NOT NULL - AND (cm2.MeasuredDBH - cm1.MeasuredDBH > 65) - AND cm1.IsValidated IS TRUE - AND cm2.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - - DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF p_CensusID IS NULL THEN - SET p_CensusID = -1; - END IF; - IF p_PlotID IS NULL THEN - SET p_PlotID = -1; - END IF; - - SELECT COUNT(*) - INTO expectedCount - FROM coremeasurements cm1 - JOIN coremeasurements cm2 - ON cm1.StemID = cm2.StemID - AND YEAR(cm2.MeasurementDate) = YEAR(cm1.MeasurementDate) + 1 - LEFT JOIN stems st2 ON cm2.StemID = st2.StemID - LEFT JOIN quadrats q ON st2.QuadratID = q.QuadratID - LEFT JOIN cmattributes cma - ON cm1.CoreMeasurementID = cma.CoreMeasurementID - LEFT JOIN attributes a - ON cma.Code = a.Code - WHERE (a.Status NOT IN ('dead', 'stem dead', 'broken below', 'missing', 'omitted') OR a.Status IS NULL) - AND cm1.MeasuredDBH IS NOT NULL - AND cm2.MeasuredDBH IS NOT NULL - AND (cm2.MeasuredDBH - cm1.MeasuredDBH > 65) - AND cm1.IsValidated IS TRUE - AND cm2.IsValidated IS FALSE - AND (p_CensusID = -1 OR q.CensusID = p_CensusID) - AND (p_PlotID = -1 OR q.PlotID = p_PlotID); - - -- Fetch the ValidationErrorID for this stored procedure - SELECT ValidationID - INTO veID - FROM catalog.validationprocedures - WHERE ProcedureName = 'ValidateDBHGrowthExceedsMax'; - - OPEN cur; - loop1: - LOOP - FETCH cur INTO vCoreMeasurementID, vPrevDBH, vCurrDBH; - IF done THEN - LEAVE loop1; - END IF; - - SET validationCriteria = 'Annual DBH Growth'; - SET measuredValue = CONCAT('Previous DBH: ', vPrevDBH, ', Current DBH: ', vCurrDBH); - SET expectedValueRange = 'Growth <= 65'; - SET additionalDetails = 'Checked for excessive DBH growth over a year'; - - IF vCurrDBH - vPrevDBH > 65 THEN - SET validationResult = 0; - SET errorMessage = 'Growth exceeds max threshold.'; - IF NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); - END IF; - INSERT INTO FailedValidations (CoreMeasurementID) VALUES (vCoreMeasurementID); - SET insertCount = insertCount + 1; - ELSE - SET validationResult = 1; - SET errorMessage = NULL; - END IF; - - INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) - VALUES ('ValidateDBHGrowthExceedsMax', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); - END LOOP; - CLOSE cur; - - SET successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); - SELECT expectedCount AS TotalRows, - insertCount AS FailedRows, - successMessage AS Message; - - SELECT CoreMeasurementID FROM FailedValidations; - - DROP TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create - definer = azureroot@`%` procedure ValidateDBHShrinkageExceedsMax(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE vCoreMeasurementID INT; - DECLARE vPrevDBH DECIMAL(10, 2); - DECLARE vCurrDBH DECIMAL(10, 2); - DECLARE validationResult BIT; - DECLARE errorMessage VARCHAR(255); - DECLARE validationCriteria TEXT; - DECLARE measuredValue VARCHAR(255); - DECLARE expectedValueRange VARCHAR(255); - DECLARE additionalDetails TEXT; - DECLARE insertCount INT DEFAULT 0; - DECLARE expectedCount INT; - DECLARE successMessage VARCHAR(255); - DECLARE veID INT; - DECLARE done INT DEFAULT FALSE; - DECLARE cur CURSOR FOR - SELECT cm2.CoreMeasurementID, cm1.MeasuredDBH, cm2.MeasuredDBH - FROM coremeasurements cm1 - JOIN coremeasurements cm2 - ON cm1.StemID = cm2.StemID - AND YEAR(cm2.MeasurementDate) = YEAR(cm1.MeasurementDate) + 1 - LEFT JOIN stems st ON cm2.StemID = st.StemID - LEFT JOIN quadrats q ON st.QuadratID = q.QuadratID - LEFT JOIN cmattributes cma - ON cm1.CoreMeasurementID = cma.CoreMeasurementID - LEFT JOIN attributes a - ON cma.Code = a.Code - WHERE (a.Status NOT IN ('dead', 'stem dead', 'broken below', 'missing', 'omitted') OR a.Status IS NULL) - AND cm1.MeasuredDBH IS NOT NULL - AND cm2.MeasuredDBH IS NOT NULL - AND cm1.IsValidated IS TRUE - AND cm2.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - - DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF p_CensusID IS NULL THEN - SET p_CensusID = -1; - END IF; - IF p_PlotID IS NULL THEN - SET p_PlotID = -1; - END IF; - - SELECT COUNT(*) - INTO expectedCount - FROM coremeasurements cm1 - JOIN coremeasurements cm2 - ON cm1.StemID = cm2.StemID - AND YEAR(cm2.MeasurementDate) = YEAR(cm1.MeasurementDate) + 1 - LEFT JOIN stems st ON cm2.StemID = st.StemID - LEFT JOIN quadrats q ON st.QuadratID = q.QuadratID - LEFT JOIN cmattributes cma - ON cm1.CoreMeasurementID = cma.CoreMeasurementID - LEFT JOIN attributes a - ON cma.Code = a.Code - WHERE (a.Status NOT IN ('dead', 'stem dead', 'broken below', 'missing', 'omitted') OR a.Status IS NULL) - AND cm1.MeasuredDBH IS NOT NULL - AND cm2.MeasuredDBH IS NOT NULL - AND cm1.IsValidated IS TRUE - AND cm2.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - - SELECT ValidationID - INTO veID - FROM catalog.validationprocedures - WHERE ProcedureName = 'ValidateDBHShrinkageExceedsMax'; - - OPEN cur; - loop1: - LOOP - FETCH cur INTO vCoreMeasurementID, vPrevDBH, vCurrDBH; - IF done THEN - LEAVE loop1; - END IF; - - SET validationCriteria = 'Annual DBH Shrinkage'; - SET measuredValue = CONCAT('Previous DBH: ', vPrevDBH, ', Current DBH: ', vCurrDBH); - SET expectedValueRange = 'Shrinkage < 5% of previous DBH'; - SET additionalDetails = 'Checked for excessive DBH shrinkage over a year'; - - IF vCurrDBH < vPrevDBH * 0.95 THEN - SET validationResult = 0; - SET errorMessage = 'Shrinkage exceeds maximum allowed threshold.'; - -- Check if the error record already exists before inserting - IF NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); - END IF; - INSERT INTO FailedValidations (CoreMeasurementID) VALUES (vCoreMeasurementID); - SET insertCount = insertCount + 1; - ELSE - SET validationResult = 1; - SET errorMessage = NULL; - END IF; - - INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) - VALUES ('ValidateDBHShrinkageExceedsMax', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); - END LOOP; - CLOSE cur; - - SET successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); - SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - - SELECT CoreMeasurementID FROM FailedValidations; - - DROP TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create - definer = azureroot@`%` procedure ValidateFindAllInvalidSpeciesCodes(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE vCoreMeasurementID INT; - DECLARE vSpeciesID INT; - DECLARE validationResult BIT; - DECLARE errorMessage VARCHAR(255); - DECLARE validationCriteria TEXT; - DECLARE measuredValue VARCHAR(255); - DECLARE expectedValueRange VARCHAR(255); - DECLARE additionalDetails TEXT; - DECLARE insertCount INT DEFAULT 0; - DECLARE expectedCount INT; - DECLARE successMessage VARCHAR(255); - DECLARE veID INT; - DECLARE done INT DEFAULT FALSE; - DECLARE cur CURSOR FOR - SELECT cm.CoreMeasurementID, sp.SpeciesID - FROM stems s - JOIN trees t ON s.TreeID = t.TreeID - LEFT JOIN species sp ON t.SpeciesID = sp.SpeciesID - JOIN coremeasurements cm ON s.StemID = cm.StemID - LEFT JOIN quadrats q ON s.QuadratID = q.QuadratID - WHERE sp.SpeciesID IS NULL - AND cm.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) - GROUP BY cm.CoreMeasurementID; - - DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF p_CensusID IS NULL THEN - SET p_CensusID = -1; - END IF; - IF p_PlotID IS NULL THEN - SET p_PlotID = -1; - END IF; - - SELECT COUNT(*) - INTO expectedCount - FROM stems s - JOIN trees t ON s.TreeID = t.TreeID - LEFT JOIN species sp ON t.SpeciesID = sp.SpeciesID - JOIN coremeasurements cm ON s.StemID = cm.StemID - LEFT JOIN quadrats q ON s.QuadratID = q.QuadratID - WHERE sp.SpeciesID IS NULL - AND cm.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) - GROUP BY cm.CoreMeasurementID; - - SELECT ValidationID - INTO veID - FROM catalog.validationprocedures - WHERE ProcedureName = 'ValidateFindAllInvalidSpeciesCodes'; - - OPEN cur; - loop1: - LOOP - FETCH cur INTO vCoreMeasurementID, vSpeciesID; - IF done THEN - LEAVE loop1; - END IF; - - SET validationCriteria = 'Species Code Validation'; - SET measuredValue = CONCAT('Species ID: ', IFNULL(vSpeciesID, 'NULL')); - SET expectedValueRange = 'Non-null and valid Species ID'; - SET additionalDetails = 'Checking for the existence of valid species codes for each measurement.'; - - IF vSpeciesID IS NULL THEN - SET validationResult = 0; - SET errorMessage = 'Invalid species code detected.'; - -- Check if the error record already exists before inserting - IF NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); - END IF; - INSERT INTO FailedValidations (CoreMeasurementID) VALUES (vCoreMeasurementID); - SET insertCount = insertCount + 1; - ELSE - SET validationResult = 1; - SET errorMessage = NULL; - END IF; - - INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) - VALUES ('ValidateFindAllInvalidSpeciesCodes', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); - END LOOP; - CLOSE cur; - - SET successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); - SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - - SELECT CoreMeasurementID FROM FailedValidations; - - DROP TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create - definer = azureroot@`%` procedure ValidateFindDuplicateStemTreeTagCombinationsPerCensus(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE vCoreMeasurementID INT; - DECLARE validationResult BIT; - DECLARE errorMessage VARCHAR(255); - DECLARE validationCriteria TEXT; - DECLARE measuredValue VARCHAR(255); - DECLARE expectedValueRange VARCHAR(255); - DECLARE additionalDetails TEXT; - DECLARE insertCount INT DEFAULT 0; - DECLARE expectedCount INT; - DECLARE successMessage VARCHAR(255); - DECLARE veID INT; - DECLARE done INT DEFAULT FALSE; - DECLARE cur CURSOR FOR - SELECT SubQuery.CoreMeasurementID - FROM (SELECT cm.CoreMeasurementID - FROM coremeasurements cm - INNER JOIN stems s ON cm.StemID = s.StemID - INNER JOIN trees t ON s.TreeID = t.TreeID - INNER JOIN quadrats q ON s.QuadratID = q.QuadratID - WHERE (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) - AND cm.IsValidated = FALSE - GROUP BY q.CensusID, s.StemTag, t.TreeTag, cm.CoreMeasurementID - HAVING COUNT(*) > 1) AS SubQuery; - - DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF p_CensusID IS NULL THEN - SET p_CensusID = -1; - END IF; - IF p_PlotID IS NULL THEN - SET p_PlotID = -1; - END IF; - - SELECT COUNT(*) - INTO expectedCount - FROM (SELECT cm.CoreMeasurementID - FROM coremeasurements cm - INNER JOIN stems s ON cm.StemID = s.StemID - INNER JOIN trees t ON s.TreeID = t.TreeID - INNER JOIN quadrats q ON s.QuadratID = q.QuadratID - WHERE (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) - AND cm.IsValidated = FALSE - GROUP BY q.CensusID, s.StemTag, t.TreeTag, cm.CoreMeasurementID - HAVING COUNT(*) > 1) AS DuplicationCheck; - - SELECT ValidationID - INTO veID - FROM catalog.validationprocedures - WHERE ProcedureName = 'ValidateFindDuplicateStemTreeTagCombinationsPerCensus'; - - - OPEN cur; - loop1: - LOOP - FETCH cur INTO vCoreMeasurementID; - IF done THEN - LEAVE loop1; - END IF; - - SET validationCriteria = 'Duplicate Stem-Tree Tag Combinations per Census'; - SET measuredValue = 'N/A'; - SET expectedValueRange = 'Unique Stem-Tree Tag Combinations'; - SET additionalDetails = 'Checking for duplicate stem and tree tag combinations in each census.'; - - IF EXISTS (SELECT 1 - FROM coremeasurements cm - INNER JOIN stems s ON cm.StemID = s.StemID - INNER JOIN trees t ON s.TreeID = t.TreeID - INNER JOIN quadrats q ON s.QuadratID = q.QuadratID - WHERE cm.CoreMeasurementID = vCoreMeasurementID - GROUP BY q.CensusID, s.StemTag, t.TreeTag - HAVING COUNT(cm.CoreMeasurementID) > 1) THEN - SET validationResult = 0; - SET errorMessage = 'Duplicate stem and tree tag combination detected.'; - -- Check if the error record already exists before inserting - IF NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); - END IF; - INSERT INTO FailedValidations (CoreMeasurementID) VALUES (vCoreMeasurementID); - SET insertCount = insertCount + 1; - ELSE - SET validationResult = 1; - SET errorMessage = NULL; - END IF; - - INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) - VALUES ('ValidateFindDuplicateStemTreeTagCombinationsPerCensus', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); - END LOOP; - CLOSE cur; - - SET successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); - SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - - SELECT CoreMeasurementID FROM FailedValidations; - - DROP TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create - definer = azureroot@`%` procedure ValidateFindDuplicatedQuadratsByName(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE vCoreMeasurementID INT; - DECLARE validationResult BIT; - DECLARE errorMessage VARCHAR(255); - DECLARE validationCriteria TEXT; - DECLARE measuredValue VARCHAR(255); - DECLARE expectedValueRange VARCHAR(255); - DECLARE additionalDetails TEXT; - DECLARE insertCount INT DEFAULT 0; - DECLARE expectedCount INT; - DECLARE successMessage VARCHAR(255); - DECLARE veID INT; - DECLARE done INT DEFAULT FALSE; - DECLARE cur CURSOR FOR - SELECT cm.CoreMeasurementID - FROM quadrats q - LEFT JOIN stems st ON q.QuadratID = st.QuadratID - JOIN coremeasurements cm ON st.StemID = cm.StemID - WHERE cm.IsValidated IS FALSE - AND (q.PlotID, q.QuadratName) IN (SELECT PlotID, QuadratName - FROM quadrats - GROUP BY PlotID, QuadratName - HAVING COUNT(*) > 1) - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) - GROUP BY cm.CoreMeasurementID; - - DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF p_CensusID IS NULL THEN - SET p_CensusID = -1; - END IF; - IF p_PlotID IS NULL THEN - SET p_PlotID = -1; - END IF; - - SELECT COUNT(*) - INTO expectedCount - FROM quadrats q - LEFT JOIN stems st ON q.QuadratID = st.QuadratID - JOIN coremeasurements cm ON st.StemID = cm.StemID - WHERE cm.IsValidated IS FALSE - AND (q.PlotID, q.QuadratName) IN (SELECT PlotID, QuadratName - FROM quadrats - GROUP BY PlotID, QuadratName - HAVING COUNT(*) > 1) - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) - GROUP BY cm.CoreMeasurementID; - - SELECT ValidationID - INTO veID - FROM catalog.validationprocedures - WHERE ProcedureName = 'ValidateFindDuplicatedQuadratsByName'; - - OPEN cur; - loop1: - LOOP - FETCH cur INTO vCoreMeasurementID; - IF done THEN - LEAVE loop1; - END IF; - - SET validationCriteria = 'Quadrat Name Duplication'; - SET measuredValue = 'N/A'; - SET expectedValueRange = 'Unique Quadrat Names per Plot'; - SET additionalDetails = 'Checking for duplicated quadrat names within the same plot.'; - - IF EXISTS (SELECT 1 - FROM quadrats q - WHERE q.QuadratID = vCoreMeasurementID - AND (q.PlotID, q.QuadratName) IN (SELECT PlotID, QuadratName - FROM quadrats - GROUP BY PlotID, QuadratName - HAVING COUNT(*) > 1)) THEN - SET validationResult = 0; - SET errorMessage = 'Duplicated quadrat name detected.'; - -- Check if the error record already exists before inserting - IF NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); - END IF; - INSERT INTO FailedValidations (CoreMeasurementID) VALUES (vCoreMeasurementID); - SET insertCount = insertCount + 1; - ELSE - SET validationResult = 1; - SET errorMessage = NULL; - END IF; - - INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) - VALUES ('ValidateFindDuplicatedQuadratsByName', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); - END LOOP; - CLOSE cur; - - SET successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); - SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - - SELECT CoreMeasurementID FROM FailedValidations; - - DROP TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create - definer = azureroot@`%` procedure ValidateFindMeasurementsOutsideCensusDateBoundsGroupByQuadrat(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE vCoreMeasurementID INT; - DECLARE validationResult BIT; - DECLARE errorMessage VARCHAR(255); - DECLARE validationCriteria TEXT; - DECLARE measuredValue VARCHAR(255); - DECLARE expectedValueRange VARCHAR(255); - DECLARE additionalDetails TEXT; - DECLARE insertCount INT DEFAULT 0; - DECLARE expectedCount INT; - DECLARE successMessage VARCHAR(255); - DECLARE veID INT; - DECLARE done INT DEFAULT FALSE; - DECLARE cur CURSOR FOR - SELECT MIN(cm.CoreMeasurementID) AS CoreMeasurementID - FROM coremeasurements cm - JOIN stems st ON cm.StemID = st.StemID - JOIN quadrats q ON st.QuadratID = q.QuadratID - JOIN census c ON q.CensusID = c.CensusID - WHERE (cm.MeasurementDate < c.StartDate OR cm.MeasurementDate > c.EndDate) - AND cm.MeasurementDate IS NOT NULL - AND cm.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR c.PlotID = p_PlotID) - GROUP BY q.QuadratID, c.CensusID, c.StartDate, c.EndDate; - - DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF p_CensusID IS NULL THEN - SET p_CensusID = -1; - END IF; - IF p_PlotID IS NULL THEN - SET p_PlotID = -1; - END IF; - - SELECT COUNT(*) - INTO expectedCount - FROM coremeasurements cm - JOIN stems st ON cm.StemID = st.StemID - JOIN quadrats q ON st.QuadratID = q.QuadratID - JOIN census c ON q.CensusID = c.CensusID - WHERE (cm.MeasurementDate < c.StartDate OR cm.MeasurementDate > c.EndDate) - AND cm.MeasurementDate IS NOT NULL - AND cm.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR c.PlotID = p_PlotID); - - SELECT ValidationID - INTO veID - FROM catalog.validationprocedures - WHERE ProcedureName = 'ValidateFindMeasurementsOutsideCensusDateBoundsGroupByQuadrat'; - - - OPEN cur; - loop1: - LOOP - FETCH cur INTO vCoreMeasurementID; - IF done THEN - LEAVE loop1; - END IF; - - SET validationCriteria = 'Measurement Date vs Census Date Bounds'; - SET measuredValue = 'Measurement Date'; - SET expectedValueRange = 'Within Census Start and End Dates'; - SET additionalDetails = - 'Checking if measurement dates fall within the start and end dates of their respective censuses.'; - - IF EXISTS (SELECT 1 - FROM coremeasurements cm - JOIN stems st ON cm.StemID = st.StemID - JOIN quadrats q ON st.QuadratID = q.QuadratID - JOIN census c ON q.CensusID = c.CensusID - WHERE cm.CoreMeasurementID = vCoreMeasurementID - AND (cm.MeasurementDate < c.StartDate OR cm.MeasurementDate > c.EndDate)) THEN - SET validationResult = 0; - SET errorMessage = 'Measurement outside census date bounds.'; - -- Check if the error record already exists before inserting - IF NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); - END IF; - INSERT INTO FailedValidations (CoreMeasurementID) VALUES (vCoreMeasurementID); - SET insertCount = insertCount + 1; - ELSE - SET validationResult = 1; - SET errorMessage = NULL; - END IF; - - INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) - VALUES ('ValidateFindMeasurementsOutsideCensusDateBoundsGroupByQuadrat', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); - END LOOP; - CLOSE cur; - - SET successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); - SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - - SELECT CoreMeasurementID FROM FailedValidations; - - DROP TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create - definer = azureroot@`%` procedure ValidateFindStemsInTreeWithDifferentSpecies(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE vCoreMeasurementID INT; - DECLARE validationResult BIT; - DECLARE errorMessage VARCHAR(255); - DECLARE validationCriteria TEXT; - DECLARE measuredValue VARCHAR(255); - DECLARE expectedValueRange VARCHAR(255); - DECLARE additionalDetails TEXT; - DECLARE insertCount INT DEFAULT 0; - DECLARE expectedCount INT; - DECLARE successMessage VARCHAR(255); - DECLARE veID INT; - DECLARE done INT DEFAULT FALSE; - - DECLARE cur CURSOR FOR - SELECT cm.CoreMeasurementID - FROM coremeasurements cm - JOIN stems s ON cm.StemID = s.StemID - JOIN trees t ON s.TreeID = t.TreeID - JOIN quadrats q ON s.QuadratID = q.QuadratID - WHERE cm.IsValidated = FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) - GROUP BY t.TreeID, cm.CoreMeasurementID - HAVING COUNT(DISTINCT t.SpeciesID) > 1; - - DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF p_CensusID IS NULL THEN - SET p_CensusID = -1; - END IF; - IF p_PlotID IS NULL THEN - SET p_PlotID = -1; - END IF; - - SELECT COUNT(*) - INTO expectedCount - FROM coremeasurements cm - JOIN stems s ON cm.StemID = s.StemID - JOIN trees t ON s.TreeID = t.TreeID - JOIN quadrats q ON s.QuadratID = q.QuadratID - WHERE cm.IsValidated = FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) - GROUP BY t.TreeID - HAVING COUNT(DISTINCT t.SpeciesID) > 1; - - SELECT ValidationID - INTO veID - FROM catalog.validationprocedures - WHERE ProcedureName = 'ValidateFindStemsInTreeWithDifferentSpecies'; - - - OPEN cur; - loop1: - LOOP - FETCH cur INTO vCoreMeasurementID; - IF done THEN - LEAVE loop1; - END IF; - - SET validationCriteria = 'Each tree should have a consistent species across all its stems.'; - SET measuredValue = 'Species consistency across tree stems'; - SET expectedValueRange = 'One species per tree'; - SET additionalDetails = 'Checking if stems belonging to the same tree have different species IDs.'; - - IF EXISTS (SELECT 1 - FROM stems s - JOIN trees t ON s.TreeID = t.TreeID - WHERE t.TreeID IN (SELECT TreeID - FROM stems - WHERE StemID IN - (SELECT StemID - FROM coremeasurements - WHERE CoreMeasurementID = vCoreMeasurementID)) - GROUP BY t.TreeID - HAVING COUNT(DISTINCT t.SpeciesID) > 1) THEN - SET validationResult = 0; - SET errorMessage = 'Stems in the same tree have different species.'; - - -- Check if the error record already exists before inserting - IF NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); - END IF; - INSERT INTO FailedValidations (CoreMeasurementID) VALUES (vCoreMeasurementID); - SET insertCount = insertCount + 1; - ELSE - SET validationResult = 1; - SET errorMessage = NULL; - END IF; - - INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) - VALUES ('ValidateFindStemsInTreeWithDifferentSpecies', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); - END LOOP; - CLOSE cur; - - SET successMessage = CONCAT('Validation completed. Total rows: ', expectedCount, ', Failed rows: ', insertCount); - SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - - SELECT CoreMeasurementID FROM FailedValidations; - - DROP TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create - definer = azureroot@`%` procedure ValidateFindStemsOutsidePlots(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE vCoreMeasurementID INT; - DECLARE validationResult BIT; - DECLARE errorMessage VARCHAR(255); - DECLARE validationCriteria TEXT; - DECLARE measuredValue VARCHAR(255); - DECLARE expectedValueRange VARCHAR(255); - DECLARE additionalDetails TEXT; - DECLARE insertCount INT DEFAULT 0; - DECLARE expectedCount INT; - DECLARE successMessage VARCHAR(255); - DECLARE veID INT; - DECLARE done INT DEFAULT FALSE; - - DECLARE cur CURSOR FOR - SELECT cm.CoreMeasurementID - FROM stems s - INNER JOIN coremeasurements cm ON s.StemID = cm.StemID - INNER JOIN quadrats q ON s.QuadratID = q.QuadratID - INNER JOIN plots p ON q.PlotID = p.PlotID - WHERE (s.LocalX > p.DimensionX OR s.LocalX > p.DimensionY) - AND s.LocalX IS NOT NULL - AND s.LocalY IS NOT NULL - AND (p.DimensionX > 0 AND p.DimensionY > 0) - AND cm.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) - GROUP BY cm.CoreMeasurementID; - - DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF p_CensusID IS NULL THEN - SET p_CensusID = -1; - END IF; - IF p_PlotID IS NULL THEN - SET p_PlotID = -1; - END IF; - - SELECT COUNT(*) - INTO expectedCount - FROM stems s - INNER JOIN quadrats q ON s.QuadratID = q.QuadratID - INNER JOIN plots p ON q.PlotID = p.PlotID - INNER JOIN coremeasurements cm ON s.StemID = cm.StemID - WHERE (s.LocalX > p.DimensionX OR s.LocalX > p.DimensionY) - AND s.LocalX IS NOT NULL - AND s.LocalY IS NOT NULL - AND (p.DimensionX > 0 AND p.DimensionY > 0) - AND cm.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - - SELECT ValidationID - INTO veID - FROM catalog.validationprocedures - WHERE ProcedureName = 'ValidateFindStemsOutsidePlots'; - - - OPEN cur; - loop1: - LOOP - FETCH cur INTO vCoreMeasurementID; - IF done THEN - LEAVE loop1; - END IF; - - SET validationCriteria = 'Stem Placement within Plot Boundaries'; - SET measuredValue = 'Stem Plot Coordinates'; - SET expectedValueRange = 'Within Plot Dimensions'; - SET additionalDetails = 'Validating whether stems are located within the specified plot dimensions.'; - - IF EXISTS (SELECT 1 - FROM stems s - INNER JOIN quadrats q ON s.QuadratID = q.QuadratID - INNER JOIN plots p ON q.PlotID = p.PlotID - WHERE s.StemID IN - (SELECT StemID - FROM coremeasurements - WHERE CoreMeasurementID = vCoreMeasurementID) - AND (s.LocalX > p.DimensionX OR s.LocalY > p.DimensionY)) THEN - SET validationResult = 0; - SET errorMessage = 'Stem is outside plot dimensions.'; - -- Check if the error record already exists before inserting - IF NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); - END IF; - INSERT INTO FailedValidations (CoreMeasurementID) VALUES (vCoreMeasurementID); - SET insertCount = insertCount + 1; - ELSE - SET validationResult = 1; - SET errorMessage = NULL; - END IF; - - INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) - VALUES ('ValidateFindStemsOutsidePlots', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); - END LOOP; - CLOSE cur; - - SET successMessage = CONCAT('Validation completed. Total rows: ', expectedCount, ', Failed rows: ', insertCount); - SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - - SELECT CoreMeasurementID FROM FailedValidations; - - DROP TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create - definer = azureroot@`%` procedure ValidateFindTreeStemsInDifferentQuadrats(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE vCoreMeasurementID INT; - DECLARE validationResult BIT; - DECLARE errorMessage VARCHAR(255); - DECLARE validationCriteria TEXT; - DECLARE measuredValue VARCHAR(255); - DECLARE expectedValueRange VARCHAR(255); - DECLARE additionalDetails TEXT; - DECLARE insertCount INT DEFAULT 0; - DECLARE expectedCount INT; - DECLARE successMessage VARCHAR(255); - DECLARE veID INT; - DECLARE done INT DEFAULT FALSE; - - DECLARE cur CURSOR FOR - SELECT cm1.CoreMeasurementID - FROM stems s1 - JOIN stems s2 ON s1.TreeID = s2.TreeID AND s1.StemID != s2.StemID - JOIN quadrats q1 ON s1.QuadratID = q1.QuadratID - JOIN quadrats q2 ON s2.QuadratID = q2.QuadratID - JOIN coremeasurements cm1 ON s1.StemID = cm1.StemID - WHERE q1.QuadratID != q2.QuadratID - AND cm1.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q1.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q1.PlotID = p_PlotID) - GROUP BY cm1.CoreMeasurementID; - - DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF p_CensusID IS NULL THEN - SET p_CensusID = -1; - END IF; - IF p_PlotID IS NULL THEN - SET p_PlotID = -1; - END IF; - - SELECT COUNT(*) - INTO expectedCount - FROM stems s1 - JOIN stems s2 ON s1.TreeID = s2.TreeID AND s1.StemID != s2.StemID - JOIN quadrats q1 ON s1.QuadratID = q1.QuadratID - JOIN quadrats q2 ON s2.QuadratID = q2.QuadratID - JOIN coremeasurements cm1 ON s1.StemID = cm1.StemID - WHERE q1.QuadratID != q2.QuadratID - AND cm1.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q1.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q1.PlotID = p_PlotID) - GROUP BY cm1.CoreMeasurementID; - - SELECT ValidationID - INTO veID - FROM catalog.validationprocedures - WHERE ProcedureName = 'ValidateFindTreeStemsInDifferentQuadrats'; - - - OPEN cur; - loop1: - LOOP - FETCH cur INTO vCoreMeasurementID; - IF done THEN - LEAVE loop1; - END IF; - - SET validationCriteria = 'Stem Quadrat Consistency within Trees'; - SET measuredValue = 'Quadrat IDs of Stems'; - SET expectedValueRange = 'Consistent Quadrat IDs for all Stems in a Tree'; - SET additionalDetails = 'Validating that all stems within the same tree are located in the same quadrat.'; - - IF EXISTS (SELECT 1 - FROM stems s1 - JOIN stems s2 ON s1.TreeID = s2.TreeID AND s1.StemID != s2.StemID - JOIN quadrats q1 on q1.QuadratID = s2.QuadratID - JOIN quadrats q2 on q2.QuadratID = s2.QuadratID - WHERE s1.StemID IN - (SELECT StemID - FROM coremeasurements - WHERE CoreMeasurementID = vCoreMeasurementID) - AND q1.QuadratID != q2.QuadratID) THEN - SET validationResult = 0; - SET errorMessage = 'Stems in the same tree are in different quadrats.'; - -- Check if the error record already exists before inserting - IF NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); - END IF; - INSERT INTO FailedValidations (CoreMeasurementID) VALUES (vCoreMeasurementID); - SET insertCount = insertCount + 1; - ELSE - SET validationResult = 1; - SET errorMessage = NULL; - END IF; - - INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) - VALUES ('ValidateFindTreeStemsInDifferentQuadrats', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); - END LOOP; - CLOSE cur; - - SET successMessage = CONCAT('Validation completed. Total rows: ', expectedCount, ', Failed rows: ', insertCount); - SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - - SELECT CoreMeasurementID FROM FailedValidations; - - DROP TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create - definer = azureroot@`%` procedure ValidateHOMUpperAndLowerBounds(IN p_CensusID int, IN p_PlotID int, - IN minHOM decimal(10, 2), IN maxHOM decimal(10, 2)) -BEGIN - DECLARE defaultMinHOM DECIMAL(10, 2); - DECLARE defaultMaxHOM DECIMAL(10, 2); - DECLARE vCoreMeasurementID INT; - DECLARE validationResult BIT; - DECLARE errorMessage VARCHAR(255); - DECLARE validationCriteria TEXT; - DECLARE measuredValue VARCHAR(255); - DECLARE expectedValueRange VARCHAR(255); - DECLARE additionalDetails TEXT; - DECLARE insertCount INT DEFAULT 0; - DECLARE expectedCount INT; - DECLARE successMessage VARCHAR(255); - DECLARE veID INT; - DECLARE done INT DEFAULT FALSE; - - DECLARE cur CURSOR FOR - SELECT cm.CoreMeasurementID - FROM coremeasurements cm - LEFT JOIN stems st ON cm.StemID = st.StemID - LEFT JOIN quadrats q ON st.QuadratID = q.QuadratID - WHERE ( - (minHOM IS NOT NULL AND MeasuredHOM < minHOM) OR - (maxHOM IS NOT NULL AND MeasuredHOM > maxHOM) OR - (minHOM IS NULL AND maxHOM IS NULL) - ) - AND IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - - DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - SELECT COUNT(*) - INTO expectedCount - FROM coremeasurements cm - LEFT JOIN stems st ON cm.StemID = st.StemID - LEFT JOIN quadrats q ON st.QuadratID = q.QuadratID - WHERE ( - (minHOM IS NOT NULL AND MeasuredHOM < minHOM) OR - (maxHOM IS NOT NULL AND MeasuredHOM > maxHOM) OR - (minHOM IS NULL AND maxHOM IS NULL) - ) - AND IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - - SELECT ValidationID - INTO veID - FROM catalog.validationprocedures - WHERE ProcedureName = 'ValidateHOMUpperAndLowerBounds'; - - - OPEN cur; - loop1: - LOOP - FETCH cur INTO vCoreMeasurementID; - - IF done THEN - LEAVE loop1; - END IF; - - IF minHOM IS NULL OR maxHOM IS NULL THEN - SELECT COALESCE(sl.LowerBound, 0) AS defaultMinHOM, - COALESCE(sl.UpperBound, 9999) AS defaultMaxHOM - INTO defaultMinHOM, defaultMaxHOM - FROM specieslimits sl - JOIN species s ON sl.SpeciesCode = s.SpeciesCode - JOIN trees t ON s.SpeciesID = t.SpeciesID - JOIN stems st ON t.TreeID = st.TreeID - JOIN coremeasurements cm ON st.StemID = cm.StemID - WHERE cm.CoreMeasurementID = vCoreMeasurementID - AND sl.LimitType = 'HOM'; - - SET minHOM = COALESCE(minHOM, defaultMinHOM); - SET maxHOM = COALESCE(maxHOM, defaultMaxHOM); - END IF; - - SET validationCriteria = 'HOM Measurement Range Validation'; - SET measuredValue = CONCAT('Measured HOM: ', (SELECT MeasuredHOM - FROM coremeasurements - WHERE CoreMeasurementID = vCoreMeasurementID)); - SET expectedValueRange = CONCAT('Expected HOM Range: ', minHOM, ' - ', maxHOM); - SET additionalDetails = 'Checks if the measured HOM falls within the specified minimum and maximum range.'; - - IF (SELECT MeasuredHOM - FROM coremeasurements - WHERE CoreMeasurementID = vCoreMeasurementID - AND ( - (minHOM IS NOT NULL AND MeasuredHOM < minHOM) OR - (maxHOM IS NOT NULL AND MeasuredHOM > maxHOM) OR - (minHOM IS NULL AND maxHOM IS NULL) - )) THEN - SET validationResult = 0; - SET errorMessage = CONCAT('HOM outside bounds: ', minHOM, ' - ', maxHOM); - INSERT INTO FailedValidations (CoreMeasurementID) VALUES (vCoreMeasurementID); - SET insertCount = insertCount + 1; - -- Check if the error record already exists before inserting - IF NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); - END IF; - ELSE - SET validationResult = 1; - SET errorMessage = NULL; - END IF; - - INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) - VALUES ('ValidateHOMUpperAndLowerBounds', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); - END LOOP; - CLOSE cur; - - SET successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); - SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - - SELECT CoreMeasurementID FROM FailedValidations; - - DROP TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create - definer = azureroot@`%` procedure ValidateScreenMeasuredDiameterMinMax(IN p_CensusID int, IN p_PlotID int, - IN minDBH decimal(10, 2), - IN maxDBH decimal(10, 2)) -BEGIN - DECLARE defaultMinDBH DECIMAL(10, 2); - DECLARE defaultMaxDBH DECIMAL(10, 2); - DECLARE vCoreMeasurementID INT; - DECLARE validationResult BIT; - DECLARE errorMessage VARCHAR(255); - DECLARE validationCriteria TEXT; - DECLARE measuredValue VARCHAR(255); - DECLARE expectedValueRange VARCHAR(255); - DECLARE additionalDetails TEXT; - DECLARE insertCount INT DEFAULT 0; - DECLARE expectedCount INT; - DECLARE successMessage VARCHAR(255); - DECLARE veID INT; - DECLARE done INT DEFAULT FALSE; - - DECLARE cur CURSOR FOR - SELECT cm.CoreMeasurementID - FROM coremeasurements cm - LEFT JOIN stems st ON cm.StemID = st.StemID - LEFT JOIN quadrats q ON st.QuadratID = q.QuadratID - WHERE ( - (MeasuredDBH < 0) OR - (maxDBH IS NOT NULL AND MeasuredDBH > maxDBH) OR - (minDBH IS NULL AND maxDBH IS NULL) - ) - AND IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - - DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - SELECT COUNT(*) - INTO expectedCount - FROM coremeasurements cm - LEFT JOIN stems st ON cm.StemID = st.StemID - LEFT JOIN quadrats q ON st.QuadratID = q.QuadratID - WHERE ( - (MeasuredDBH < 0) OR - (maxDBH IS NOT NULL AND MeasuredDBH > maxDBH) OR - (minDBH IS NULL AND maxDBH IS NULL) - ) - AND IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - - SELECT ValidationID - INTO veID - FROM catalog.validationprocedures - WHERE ProcedureName = 'ValidateScreenMeasuredDiameterMinMax'; - - - OPEN cur; - loop1: - LOOP - FETCH cur INTO vCoreMeasurementID; - - IF done THEN - LEAVE loop1; - END IF; - - IF minDBH IS NULL OR maxDBH IS NULL THEN - SELECT COALESCE(sl.LowerBound, 0) AS defaultMinDBH, - COALESCE(sl.UpperBound, 9999) AS defaultMaxDBH - INTO defaultMinDBH, defaultMaxDBH - FROM specieslimits sl - JOIN species s ON sl.SpeciesCode = s.SpeciesCode - JOIN trees t ON s.SpeciesID = t.SpeciesID - JOIN stems st ON t.TreeID = st.TreeID - JOIN coremeasurements cm ON st.StemID = cm.StemID - WHERE cm.CoreMeasurementID = vCoreMeasurementID - AND sl.LimitType = 'DBH'; - - SET minDBH = COALESCE(minDBH, defaultMinDBH); - SET maxDBH = COALESCE(maxDBH, defaultMaxDBH); - END IF; - - SET validationCriteria = 'DBH Measurement Range Validation'; - SET measuredValue = CONCAT('Measured DBH: ', (SELECT MeasuredDBH - FROM coremeasurements - WHERE CoreMeasurementID = vCoreMeasurementID)); - SET expectedValueRange = CONCAT('Expected DBH Range: ', minDBH, ' - ', maxDBH); - SET additionalDetails = 'Checks if the measured DBH falls within the specified minimum and maximum range.'; - - IF (SELECT MeasuredDBH - FROM coremeasurements - WHERE CoreMeasurementID = vCoreMeasurementID - AND ( - (MeasuredDBH < 0) OR - (maxDBH IS NOT NULL AND MeasuredDBH > maxDBH) OR - (minDBH IS NULL AND maxDBH IS NULL) - )) THEN - SET validationResult = 0; - SET errorMessage = CONCAT('DBH outside bounds: ', minDBH, ' - ', maxDBH); - INSERT INTO FailedValidations (CoreMeasurementID) VALUES (vCoreMeasurementID); - SET insertCount = insertCount + 1; - -- Check if the error record already exists before inserting - IF NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); - END IF; - ELSE - SET validationResult = 1; - SET errorMessage = NULL; - END IF; - - INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) - VALUES ('ValidateScreenMeasuredDiameterMinMax', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); - END LOOP; - CLOSE cur; - - SET successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); - SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - - SELECT CoreMeasurementID FROM FailedValidations; - - DROP TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create - definer = azureroot@`%` procedure ValidateScreenStemsWithMeasurementsButDeadAttributes(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE vCoreMeasurementID INT; - DECLARE validationResult BIT; - DECLARE errorMessage VARCHAR(255); - DECLARE validationCriteria TEXT; - DECLARE additionalDetails TEXT; - DECLARE insertCount INT DEFAULT 0; - DECLARE expectedCount INT; - DECLARE successMessage VARCHAR(255); - DECLARE done INT DEFAULT FALSE; - DECLARE veID INT; - DECLARE vExistingErrorID INT; - - DECLARE cur CURSOR FOR - SELECT cm.CoreMeasurementID - FROM coremeasurements cm - JOIN cmattributes cma ON cm.CoreMeasurementID = cma.CoreMeasurementID - JOIN attributes a ON cma.Code = a.Code - JOIN stems st ON cm.StemID = st.StemID - JOIN quadrats q ON st.QuadratID = q.QuadratID - WHERE ((cm.MeasuredDBH IS NOT NULL AND cm.MeasuredDBH > 0) OR - (cm.MeasuredHOM IS NOT NULL AND cm.MeasuredHOM > 0)) - AND a.Status IN ('dead', 'stem dead', 'missing', 'broken below', 'omitted') - AND cm.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - - DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - SELECT COUNT(*) - INTO expectedCount - FROM coremeasurements cm - JOIN cmattributes cma ON cm.CoreMeasurementID = cma.CoreMeasurementID - JOIN attributes a ON cma.Code = a.Code - JOIN stems st ON cm.StemID = st.StemID - JOIN quadrats q ON st.QuadratID = q.QuadratID - WHERE ((cm.MeasuredDBH IS NOT NULL AND cm.MeasuredDBH > 0) OR - (cm.MeasuredHOM IS NOT NULL AND cm.MeasuredHOM > 0)) - AND a.Status IN ('dead', 'stem dead', 'missing', 'broken below', 'omitted') - AND cm.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - - SELECT ValidationID - INTO veID - FROM catalog.validationprocedures - WHERE ProcedureName = 'ValidateScreenStemsWithMeasurementsButDeadAttributes'; - - - OPEN cur; - loop1: - LOOP - FETCH cur INTO vCoreMeasurementID; - IF done THEN - LEAVE loop1; - END IF; - - SET validationCriteria = 'Stem Measurements with Dead Attributes Validation'; - SET additionalDetails = 'Verifies that stems marked as dead do not have active measurements.'; - - IF EXISTS (SELECT 1 - FROM cmattributes cma - JOIN attributes a ON cma.Code = a.Code - JOIN coremeasurements cm on cma.CoreMeasurementID = cm.CoreMeasurementID - WHERE cma.CoreMeasurementID = vCoreMeasurementID - AND a.Status IN ('dead', 'stem dead', 'missing', 'broken below', 'omitted') - AND ((cm.MeasuredDBH IS NOT NULL AND cm.MeasuredDBH > 0) OR - (cm.MeasuredHOM IS NOT NULL AND cm.MeasuredHOM > 0))) THEN - SET validationResult = 0; - SET errorMessage = 'Stem with measurements but dead attributes detected.'; - -- Check if the error record already exists before inserting - IF NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); - END IF; - INSERT INTO FailedValidations (CoreMeasurementID) VALUES (vCoreMeasurementID); - SET insertCount = insertCount + 1; - ELSE - SET validationResult = 1; - SET errorMessage = NULL; - END IF; - - INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, AdditionalDetails) - VALUES ('ValidateScreenStemsWithMeasurementsButDeadAttributes', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, additionalDetails); - END LOOP; - CLOSE cur; - - SET successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); - SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - - SELECT CoreMeasurementID FROM FailedValidations; - - DROP TEMPORARY TABLE IF EXISTS FailedValidations; -END; - diff --git a/frontend/sqlscripting/coverageindexes.sql b/frontend/sqlscripting/coverageindexes.sql deleted file mode 100644 index ebd423be..00000000 --- a/frontend/sqlscripting/coverageindexes.sql +++ /dev/null @@ -1,86 +0,0 @@ -create index idx_coremeasurementid_coremeasurements on coremeasurements (CoreMeasurementID); -create index idx_censusid_coremeasurements on coremeasurements (CensusID); -create index idx_stemid_coremeasurements on coremeasurements (StemID); -create index idx_measurementdate_coremeasurements on coremeasurements (MeasurementDate); -create index idx_cmid_cid_coremeasurements on coremeasurements (CoreMeasurementID, CensusID); -create index idx_cmid_cid_sid_coremeasurements on coremeasurements (CoreMeasurementID, CensusID, StemID); - -create index idx_stemid_stems on stems (StemID); -create index idx_treeid_stems on stems (TreeID); -create index idx_quadratid_stems on stems (QuadratID); -create index idx_stemid_treeid_stems on stems (StemID, TreeID); -create index idx_sid_tid_qid_stems on stems (StemID, TreeID, QuadratID); - -create index idx_quadratid_quadrats on quadrats (QuadratID); -create index idx_plotid_quadrats on quadrats (PlotID); -create index idx_censusid_quadrats on quadrats (CensusID); -create index idx_qid_pid_quadrats on quadrats (QuadratID, PlotID); -create index idx_pid_cid_quadrats on quadrats (PlotID, CensusID); -create index idx_qid_pid_cid_quadrats on quadrats (QuadratID, PlotID, CensusID); - --- DEPRECATED --- Covering indexes for alltaxonomiesview -CREATE INDEX idx_family_covering_family ON family (FamilyID, Family(32)); -CREATE INDEX idx_genus_covering_genus ON genus (GenusID, FamilyID, Genus(32), GenusAuthority(32)); -CREATE INDEX idx_species_covering_species ON species (SpeciesID, GenusID, SpeciesCode(25), SpeciesName(64), - SubspeciesName(64), IDLevel(20), SpeciesAuthority(64), - SubspeciesAuthority(64), ValidCode(100), FieldFamily(32), - Description(100), ReferenceID); -CREATE INDEX idx_reference_covering_reference ON reference (ReferenceID, PublicationTitle(64), FullReference(100), - DateOfPublication, Citation(50)); - --- Covering indexes for measurementssummaryview -CREATE INDEX idx_coremeasurements_covering_coremeasurements ON coremeasurements (CoreMeasurementID, CensusID, StemID, - MeasurementDate, MeasuredDBH, DBHUnit, - MeasuredHOM, HOMUnit, IsValidated, - Description(100)); -CREATE INDEX idx_stems_covering_stems ON stems (StemID, TreeID, QuadratID, LocalX, LocalY, CoordinateUnits); -CREATE INDEX idx_trees_covering_trees ON trees (TreeID, SpeciesID, TreeTag(10)); -CREATE INDEX idx_species_covering_species_measurement ON species (SpeciesID, GenusID, SpeciesCode(25)); -CREATE INDEX idx_genus_covering_genus_measurement ON genus (GenusID, FamilyID); -CREATE INDEX idx_family_covering_family_measurement ON family (FamilyID); -CREATE INDEX idx_quadrats_covering_quadrats ON quadrats (QuadratID, PlotID, QuadratName(64)); -CREATE INDEX idx_plots_covering_plots ON plots (PlotID, PlotName(255)); -CREATE INDEX idx_census_covering_census ON census (CensusID); -CREATE INDEX idx_quadratpersonnel_covering_quadratpersonnel ON quadratpersonnel (QuadratID, PersonnelID); -CREATE INDEX idx_personnel_covering_personnel ON personnel (PersonnelID, FirstName(50), LastName(50)); -CREATE INDEX idx_cmattributes_covering_cmattributes ON cmattributes (CoreMeasurementID, Code(10)); - --- Covering indexes for stemtaxonomiesview -CREATE INDEX idx_stems_covering_stems_taxonomies ON stems (StemID, TreeID, QuadratID, LocalX, LocalY, CoordinateUnits); -CREATE INDEX idx_trees_covering_trees_taxonomies ON trees (TreeID, SpeciesID, TreeTag(10)); -CREATE INDEX idx_quadrats_covering_quadrats_taxonomies ON quadrats (QuadratID, PlotID, QuadratName(64)); -CREATE INDEX idx_census_covering_census_taxonomies ON census (CensusID, PlotID); -CREATE INDEX idx_plots_covering_plots_taxonomies ON plots (PlotID, PlotName(255)); -CREATE INDEX idx_species_covering_species_taxonomies ON species (SpeciesID, GenusID, SpeciesCode(25), SpeciesName(64), - SubspeciesName(64), IDLevel(20), SpeciesAuthority(64), - SubspeciesAuthority(64), ValidCode(100), - FieldFamily(32)); -CREATE INDEX idx_genus_covering_genus_taxonomies ON genus (GenusID, FamilyID, Genus(32), GenusAuthority(32)); -CREATE INDEX idx_family_covering_family_taxonomies ON family (FamilyID, Family(32)); - --- Covering indexes for viewfulltableview -CREATE INDEX idx_coremeasurements_covering_coremeasurements_full ON coremeasurements (CoreMeasurementID, - MeasurementDate, MeasuredDBH, - DBHUnit, MeasuredHOM, HOMUnit, - IsValidated, Description(100)); -CREATE INDEX idx_stems_covering_stems_full ON stems (StemID, TreeID, QuadratID, LocalX, LocalY, CoordinateUnits); -CREATE INDEX idx_trees_covering_trees_full ON trees (TreeID, SpeciesID, TreeTag(10)); -CREATE INDEX idx_species_covering_species_full ON species (SpeciesID, GenusID, SpeciesCode(25), SpeciesName(64), - SubspeciesName(64), SubspeciesAuthority(64), IDLevel(20)); -CREATE INDEX idx_genus_covering_genus_full ON genus (GenusID, FamilyID, Genus(32), GenusAuthority(32)); -CREATE INDEX idx_family_covering_family_full ON family (FamilyID, Family(32)); -CREATE INDEX idx_specieslimits_covering_specieslimits_full ON specieslimits (SpeciesCode(25)); -CREATE INDEX idx_quadrats_covering_quadrats_full ON quadrats (QuadratID, PlotID, QuadratName(64), DimensionX, - DimensionY, Area, QuadratShape(64), DimensionUnits); -CREATE INDEX idx_quadratpersonnel_covering_quadratpersonnel_full ON quadratpersonnel (QuadratID, PersonnelID); -CREATE INDEX idx_personnel_covering_personnel_full ON personnel (PersonnelID, FirstName(50), LastName(50), RoleID); -CREATE INDEX idx_plots_covering_plots_full ON plots (PlotID, PlotName(100), LocationName(100), CountryName(100), - DimensionX, DimensionY, Area, GlobalX, GlobalY, GlobalZ, - DimensionUnits, PlotShape(64), PlotDescription(100)); -CREATE INDEX idx_subquadrats_covering_subquadrats_full ON subquadrats (SubquadratID, SubquadratName(25), DimensionX, - DimensionY, QX, QY, CoordinateUnits); -CREATE INDEX idx_census_covering_census_full ON census (CensusID, StartDate, EndDate, Description(100), PlotCensusNumber); -CREATE INDEX idx_roles_covering_roles_full ON roles (RoleID, RoleName(255)); -CREATE INDEX idx_attributes_covering_attributes_full ON attributes (Code(10), Description(100), Status); -CREATE INDEX idx_cmattributes_covering_cmattributes_full ON cmattributes (CoreMeasurementID, Code(10)); diff --git a/frontend/sqlscripting/drop_all_triggers.sql b/frontend/sqlscripting/drop_all_triggers.sql deleted file mode 100644 index 0045b507..00000000 --- a/frontend/sqlscripting/drop_all_triggers.sql +++ /dev/null @@ -1,230 +0,0 @@ -# attributes -DROP TRIGGER IF EXISTS after_insert_attributes; -DROP TRIGGER IF EXISTS after_update_attributes; -DROP TRIGGER IF EXISTS after_delete_attributes; - -# census -DROP TRIGGER IF EXISTS after_insert_census; -DROP TRIGGER IF EXISTS after_update_census; -DROP TRIGGER IF EXISTS after_delete_census; - -# cmattributes -DROP TRIGGER IF EXISTS after_insert_cmattributes; -DROP TRIGGER IF EXISTS after_update_cmattributes; -DROP TRIGGER IF EXISTS after_delete_cmattributes; - -# cmverrors -DROP TRIGGER IF EXISTS after_insert_cmverrors; -DROP TRIGGER IF EXISTS after_update_cmverrors; -DROP TRIGGER IF EXISTS after_delete_cmverrors; - -# coremeasurements -DROP TRIGGER IF EXISTS after_insert_coremeasurements; -DROP TRIGGER IF EXISTS after_update_coremeasurements; -DROP TRIGGER IF EXISTS after_delete_coremeasurements; - -# family -DROP TRIGGER IF EXISTS after_insert_family; -DROP TRIGGER IF EXISTS after_update_family; -DROP TRIGGER IF EXISTS after_delete_family; - -# genus -DROP TRIGGER IF EXISTS after_insert_genus; -DROP TRIGGER IF EXISTS after_update_genus; -DROP TRIGGER IF EXISTS after_delete_genus; - -# personnel -DROP TRIGGER IF EXISTS after_insert_personnel; -DROP TRIGGER IF EXISTS after_update_personnel; -DROP TRIGGER IF EXISTS after_delete_personnel; - -# plots -DROP TRIGGER IF EXISTS after_insert_plots; -DROP TRIGGER IF EXISTS after_update_plots; -DROP TRIGGER IF EXISTS after_delete_plots; - -# quadratpersonnel -DROP TRIGGER IF EXISTS after_insert_quadratpersonnel; -DROP TRIGGER IF EXISTS after_update_quadratpersonnel; -DROP TRIGGER IF EXISTS after_delete_quadratpersonnel; - -# quadrats -DROP TRIGGER IF EXISTS after_insert_quadrats; -DROP TRIGGER IF EXISTS after_update_quadrats; -DROP TRIGGER IF EXISTS after_delete_quadrats; - -# reference -DROP TRIGGER IF EXISTS after_insert_reference; -DROP TRIGGER IF EXISTS after_update_reference; -DROP TRIGGER IF EXISTS after_delete_reference; - -# roles -DROP TRIGGER IF EXISTS after_insert_roles; -DROP TRIGGER IF EXISTS after_update_roles; -DROP TRIGGER IF EXISTS after_delete_roles; - -# species -DROP TRIGGER IF EXISTS after_insert_species; -DROP TRIGGER IF EXISTS after_update_species; -DROP TRIGGER IF EXISTS after_delete_species; - -# specieslimits -DROP TRIGGER IF EXISTS after_insert_specieslimits; -DROP TRIGGER IF EXISTS after_update_specieslimits; -DROP TRIGGER IF EXISTS after_delete_specieslimits; - -# specimens -DROP TRIGGER IF EXISTS after_insert_specimens; -DROP TRIGGER IF EXISTS after_update_specimens; -DROP TRIGGER IF EXISTS after_delete_specimens; - -# stems -DROP TRIGGER IF EXISTS after_insert_stems; -DROP TRIGGER IF EXISTS after_update_stems; -DROP TRIGGER IF EXISTS after_delete_stems; - -# subquadrats -DROP TRIGGER IF EXISTS after_insert_subquadrats; -DROP TRIGGER IF EXISTS after_update_subquadrats; -DROP TRIGGER IF EXISTS after_delete_subquadrats; - -# trees -DROP TRIGGER IF EXISTS after_insert_trees; -DROP TRIGGER IF EXISTS after_update_trees; -DROP TRIGGER IF EXISTS after_delete_trees; - -# validationchangelog -DROP TRIGGER IF EXISTS after_insert_validationchangelog; -DROP TRIGGER IF EXISTS after_update_validationchangelog; -DROP TRIGGER IF EXISTS after_delete_validationchangelog; - -# materialized view triggers: measurementssummaryview -DROP TRIGGER IF EXISTS trg_coremeasurements_refresh_measurementssummary_after_insert; -DROP TRIGGER IF EXISTS trg_coremeasurements_refresh_measurementssummary_after_update; -DROP TRIGGER IF EXISTS trg_coremeasurements_refresh_measurementssummary_after_delete; -DROP TRIGGER IF EXISTS trg_cmattributes_refresh_measurementssummary_after_insert; -DROP TRIGGER IF EXISTS trg_cmattributes_refresh_measurementssummary_after_update; -DROP TRIGGER IF EXISTS trg_cmattributes_refresh_measurementssummary_after_delete; -DROP TRIGGER IF EXISTS trg_stems_refresh_measurementssummary_after_insert; -DROP TRIGGER IF EXISTS trg_stems_refresh_measurementssummary_after_update; -DROP TRIGGER IF EXISTS trg_stems_refresh_measurementssummary_after_delete; -DROP TRIGGER IF EXISTS trg_trees_refresh_measurementssummary_after_insert; -DROP TRIGGER IF EXISTS trg_trees_refresh_measurementssummary_after_update; -DROP TRIGGER IF EXISTS trg_trees_refresh_measurementssummary_after_delete; -DROP TRIGGER IF EXISTS trg_species_refresh_measurementssummary_after_insert; -DROP TRIGGER IF EXISTS trg_species_refresh_measurementssummary_after_update; -DROP TRIGGER IF EXISTS trg_species_refresh_measurementssummary_after_delete; -DROP TRIGGER IF EXISTS trg_quadrats_refresh_measurementssummary_after_insert; -DROP TRIGGER IF EXISTS trg_quadrats_refresh_measurementssummary_after_update; -DROP TRIGGER IF EXISTS trg_quadrats_refresh_measurementssummary_after_delete; -DROP TRIGGER IF EXISTS trg_census_refresh_measurementssummary_after_insert; -DROP TRIGGER IF EXISTS trg_census_refresh_measurementssummary_after_update; -DROP TRIGGER IF EXISTS trg_census_refresh_measurementssummary_after_delete; - -# materialized view triggers: viewfulltable -DROP TRIGGER IF EXISTS trg_coremeasurements_refresh_viewfulltable_after_insert; -DROP TRIGGER IF EXISTS trg_coremeasurements_refresh_viewfulltable_after_update; -DROP TRIGGER IF EXISTS trg_coremeasurements_refresh_viewfulltable_after_delete; -DROP TRIGGER IF EXISTS trg_cmattributes_refresh_viewfulltable_after_insert; -DROP TRIGGER IF EXISTS trg_cmattributes_refresh_viewfulltable_after_update; -DROP TRIGGER IF EXISTS trg_cmattributes_refresh_viewfulltable_after_delete; -DROP TRIGGER IF EXISTS trg_stems_refresh_viewfulltable_after_insert; -DROP TRIGGER IF EXISTS trg_stems_refresh_viewfulltable_after_update; -DROP TRIGGER IF EXISTS trg_stems_refresh_viewfulltable_after_delete; -DROP TRIGGER IF EXISTS trg_trees_refresh_viewfulltable_after_insert; -DROP TRIGGER IF EXISTS trg_trees_refresh_viewfulltable_after_update; -DROP TRIGGER IF EXISTS trg_trees_refresh_viewfulltable_after_delete; -DROP TRIGGER IF EXISTS trg_species_refresh_viewfulltable_after_insert; -DROP TRIGGER IF EXISTS trg_species_refresh_viewfulltable_after_update; -DROP TRIGGER IF EXISTS trg_species_refresh_viewfulltable_after_delete; -DROP TRIGGER IF EXISTS trg_quadrats_refresh_viewfulltable_after_insert; -DROP TRIGGER IF EXISTS trg_quadrats_refresh_viewfulltable_after_update; -DROP TRIGGER IF EXISTS trg_quadrats_refresh_viewfulltable_after_delete; -DROP TRIGGER IF EXISTS trg_census_refresh_viewfulltable_after_insert; -DROP TRIGGER IF EXISTS trg_census_refresh_viewfulltable_after_update; -DROP TRIGGER IF EXISTS trg_census_refresh_viewfulltable_after_delete; - -# set refresh triggers: --- Drop triggers for coremeasurements -DROP TRIGGER IF EXISTS trg_coremeasurements_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_coremeasurements_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_coremeasurements_set_refresh_needed_after_delete; - --- Drop triggers for stems -DROP TRIGGER IF EXISTS trg_stems_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_stems_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_stems_set_refresh_needed_after_delete; - --- Drop triggers for trees -DROP TRIGGER IF EXISTS trg_trees_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_trees_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_trees_set_refresh_needed_after_delete; - --- Drop triggers for species -DROP TRIGGER IF EXISTS trg_species_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_species_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_species_set_refresh_needed_after_delete; - --- Drop triggers for quadrats -DROP TRIGGER IF EXISTS trg_quadrats_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_quadrats_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_quadrats_set_refresh_needed_after_delete; - --- Drop triggers for census -DROP TRIGGER IF EXISTS trg_census_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_census_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_census_set_refresh_needed_after_delete; - --- Drop triggers for cmattributes -DROP TRIGGER IF EXISTS trg_cmattributes_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_cmattributes_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_cmattributes_set_refresh_needed_after_delete; - --- Drop triggers for plots -DROP TRIGGER IF EXISTS trg_plots_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_plots_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_plots_set_refresh_needed_after_delete; - --- Drop triggers for subquadrats -DROP TRIGGER IF EXISTS trg_subquadrats_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_subquadrats_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_subquadrats_set_refresh_needed_after_delete; - --- Drop triggers for roles -DROP TRIGGER IF EXISTS trg_roles_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_roles_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_roles_set_refresh_needed_after_delete; - --- Drop triggers for attributes -DROP TRIGGER IF EXISTS trg_attributes_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_attributes_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_attributes_set_refresh_needed_after_delete; - --- Drop triggers for genus -DROP TRIGGER IF EXISTS trg_genus_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_genus_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_genus_set_refresh_needed_after_delete; - --- Drop triggers for family -DROP TRIGGER IF EXISTS trg_family_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_family_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_family_set_refresh_needed_after_delete; - --- Drop triggers for specieslimits -DROP TRIGGER IF EXISTS trg_specieslimits_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_specieslimits_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_specieslimits_set_refresh_needed_after_delete; - --- Drop triggers for quadratpersonnel -DROP TRIGGER IF EXISTS trg_quadratpersonnel_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_quadratpersonnel_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_quadratpersonnel_set_refresh_needed_after_delete; - --- Drop triggers for personnel -DROP TRIGGER IF EXISTS trg_personnel_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_personnel_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_personnel_set_refresh_needed_after_delete; - --- Drop triggers for batchprocessingflag -DROP TRIGGER IF EXISTS trg_batchprocessingflag_before_insert; -DROP TRIGGER IF EXISTS trg_batchprocessingflag_after_update; diff --git a/frontend/sqlscripting/internalvalidationskeleton.sql b/frontend/sqlscripting/internalvalidationskeleton.sql deleted file mode 100644 index ed8b5ad2..00000000 --- a/frontend/sqlscripting/internalvalidationskeleton.sql +++ /dev/null @@ -1,101 +0,0 @@ --- intended for internal use, this is a skeleton validation procedure that can be quickly and easily filled out to more easily implement new procedures: - -CREATE DEFINER = azureroot@`%` PROCEDURE ValidateSkeleton( - IN p_CensusID INT, - IN p_PlotID INT, - IN minHOM DECIMAL(10, 2) DEFAULT NULL, - IN maxHOM DECIMAL(10, 2) DEFAULT NULL, - IN minDBH DECIMAL(10, 2) DEFAULT NULL, - IN maxDBH DECIMAL(10, 2) DEFAULT NULL -) -BEGIN - DECLARE vCoreMeasurementID INT; - DECLARE validationResult BIT; - DECLARE errorMessage VARCHAR(255); - DECLARE validationCriteria TEXT; - DECLARE measuredValue VARCHAR(255); - DECLARE expectedValueRange VARCHAR(255); - DECLARE additionalDetails TEXT; - DECLARE insertCount INT DEFAULT 0; - DECLARE expectedCount INT; - DECLARE successMessage VARCHAR(255); - DECLARE veID INT; - DECLARE done INT DEFAULT FALSE; - - DECLARE cur CURSOR FOR -SELECT /* Columns needed for validation */ -FROM /* Relevant tables and joins */ - WHERE /* Validation conditions */ - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - -DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE TEMPORARY TABLE IF NOT EXISTS FailedValidations ( - CoreMeasurementID INT - ); - - IF p_CensusID IS NULL THEN - SET p_CensusID = -1; -END IF; - IF p_PlotID IS NULL THEN - SET p_PlotID = -1; -END IF; - -SELECT COUNT(*) -INTO expectedCount -FROM /* Relevant tables and joins */ - WHERE /* Validation conditions */ - AND (p_CensusID = -1 OR q.CensusID = p_CensusID) - AND (p_PlotID = -1 OR q.PlotID = p_PlotID); - -/*SELECT ValidationID -INTO veID -FROM catalog.validationprocedures -WHERE ProcedureName = 'YourProcedureName';*/ - -OPEN cur; -loop1: LOOP - FETCH cur INTO vCoreMeasurementID; - IF done THEN - LEAVE loop1; -END IF; - - SET validationCriteria = 'Your Validation Criteria'; - SET measuredValue = 'Your Measured Value'; - SET expectedValueRange = 'Your Expected Value Range'; - SET additionalDetails = 'Additional Details for Validation'; - - IF /* Your validation logic */ THEN - SET validationResult = 0; - SET errorMessage = 'Your Error Message'; - IF NOT EXISTS (SELECT 1 FROM cmverrors WHERE CoreMeasurementID = vCoreMeasurementID AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); -END IF; -INSERT INTO FailedValidations (CoreMeasurementID) -VALUES (vCoreMeasurementID); -SET insertCount = insertCount + 1; -ELSE - SET validationResult = 1; - SET errorMessage = NULL; -END IF; - -INSERT INTO validationchangelog ( - ProcedureName, RunDateTime, TargetRowID, ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, AdditionalDetails -) VALUES ( - 'YourProcedureName', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, additionalDetails - ); -END LOOP; -CLOSE cur; - -SET successMessage = CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); -SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - -SELECT CoreMeasurementID FROM FailedValidations; - -DROP TEMPORARY TABLE IF EXISTS FailedValidations; -END; diff --git a/frontend/sqlscripting/materializedviewrefreshprocedures.sql b/frontend/sqlscripting/materializedviewrefreshprocedures.sql deleted file mode 100644 index 0d4975bf..00000000 --- a/frontend/sqlscripting/materializedviewrefreshprocedures.sql +++ /dev/null @@ -1,104 +0,0 @@ -create - definer = azureroot@`%` procedure RefreshMeasurementsSummary() -BEGIN - TRUNCATE TABLE measurementssummary; - INSERT INTO measurementssummary - SELECT cm.CoreMeasurementID AS CoreMeasurementID, - st.StemID AS StemID, - t.TreeID AS TreeID, - s.SpeciesID AS SpeciesID, - q.QuadratID AS QuadratID, - q.PlotID AS PlotID, - cm.CensusID AS CensusID, - s.SpeciesName AS SpeciesName, - s.SubspeciesName AS SubspeciesName, - s.SpeciesCode AS SpeciesCode, - t.TreeTag AS TreeTag, - st.StemTag AS StemTag, - st.LocalX AS StemLocalX, - st.LocalY AS StemLocalY, - st.CoordinateUnits AS StemUnits, - q.QuadratName AS QuadratName, - cm.MeasurementDate AS MeasurementDate, - cm.MeasuredDBH AS MeasuredDBH, - cm.DBHUnit AS DBHUnits, - cm.MeasuredHOM AS MeasuredHOM, - cm.HOMUnit AS HOMUnits, - cm.IsValidated AS IsValidated, - cm.Description AS Description, - (SELECT GROUP_CONCAT(ca.Code SEPARATOR '; ') - FROM cmattributes ca - WHERE ca.CoreMeasurementID = cm.CoreMeasurementID) AS Attributes - FROM coremeasurements cm - LEFT JOIN stems st ON cm.StemID = st.StemID - LEFT JOIN trees t ON st.TreeID = t.TreeID - LEFT JOIN species s ON t.SpeciesID = s.SpeciesID - LEFT JOIN quadrats q ON st.QuadratID = q.QuadratID - LEFT JOIN census c ON cm.CensusID = c.CensusID; -END; - -create - definer = azureroot@`%` procedure RefreshViewFullTable() -BEGIN - -- Truncate the materialized table - TRUNCATE TABLE viewfulltable; - --- Insert data from the view into the materialized table - INSERT INTO viewfulltable - SELECT cm.CoreMeasurementID AS CoreMeasurementID, - t.TreeID AS TreeID, - s.StemID AS StemID, - sp.SpeciesID AS SpeciesID, - g.GenusID AS GenusID, - f.FamilyID AS FamilyID, - q.QuadratID AS QuadratID, - p.PlotID AS PlotID, - c.CensusID AS CensusID, - cm.MeasurementDate AS MeasurementDate, - cm.MeasuredDBH AS MeasuredDBH, - cm.DBHUnit AS DBHUnits, - cm.MeasuredHOM AS MeasuredHOM, - cm.HOMUnit AS HOMUnits, - cm.Description AS Description, - cm.IsValidated AS IsValidated, - p.PlotName AS PlotName, - p.LocationName AS LocationName, - p.CountryName AS CountryName, - p.GlobalX AS GlobalX, - p.GlobalY AS GlobalY, - p.GlobalY AS GlobalZ, - q.QuadratName AS QuadratName, - q.StartX AS QuadratX, - q.StartY AS QuadratY, - c.PlotCensusNumber AS PlotCensusNumber, - c.StartDate AS StartDate, - c.EndDate AS EndDate, - t.TreeTag AS TreeTag, - s.StemTag AS StemTag, - s.LocalX AS StemLocalX, - s.LocalY AS StemLocalY, - s.CoordinateUnits AS StemUnits, - sp.SpeciesCode AS SpeciesCode, - sp.SpeciesName AS SpeciesName, - sp.SubspeciesName AS SubspeciesName, - sp.ValidCode AS ValidCode, - sp.SpeciesAuthority AS SpeciesAuthority, - sp.SubspeciesAuthority AS SubspeciesAuthority, - sp.IDLevel AS SpeciesIDLevel, - sp.FieldFamily AS SpeciesFieldFamily, - g.Genus AS Genus, - g.GenusAuthority AS GenusAuthority, - f.Family AS Family, - (SELECT GROUP_CONCAT(ca.Code SEPARATOR '; ') - FROM cmattributes ca - WHERE ca.CoreMeasurementID = cm.CoreMeasurementID) AS Attributes - FROM coremeasurements cm - LEFT JOIN stems s ON cm.StemID = s.StemID - LEFT JOIN trees t ON s.TreeID = t.TreeID - LEFT JOIN species sp ON t.SpeciesID = sp.SpeciesID - LEFT JOIN genus g ON sp.GenusID = g.GenusID - LEFT JOIN family f ON g.FamilyID = f.FamilyID - LEFT JOIN quadrats q ON s.QuadratID = q.QuadratID - LEFT JOIN census c ON cm.CensusID = c.CensusID - LEFT JOIN plots p ON q.PlotID = p.PlotID; -END; \ No newline at end of file diff --git a/frontend/sqlscripting/materializedviews/fulltriggers.sql b/frontend/sqlscripting/materializedviews/fulltriggers.sql deleted file mode 100644 index d0a5433c..00000000 --- a/frontend/sqlscripting/materializedviews/fulltriggers.sql +++ /dev/null @@ -1,427 +0,0 @@ --- Create triggers for coremeasurements -CREATE TRIGGER trg_coremeasurements_set_refresh_needed_after_insert - AFTER INSERT - ON coremeasurements - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_coremeasurements_set_refresh_needed_after_update - AFTER UPDATE - ON coremeasurements - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_coremeasurements_set_refresh_needed_after_delete - AFTER DELETE - ON coremeasurements - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for stems -CREATE TRIGGER trg_stems_set_refresh_needed_after_insert - AFTER INSERT - ON stems - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_stems_set_refresh_needed_after_update - AFTER UPDATE - ON stems - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_stems_set_refresh_needed_after_delete - AFTER DELETE - ON stems - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for trees -CREATE TRIGGER trg_trees_set_refresh_needed_after_insert - AFTER INSERT - ON trees - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_trees_set_refresh_needed_after_update - AFTER UPDATE - ON trees - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_trees_set_refresh_needed_after_delete - AFTER DELETE - ON trees - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for species -CREATE TRIGGER trg_species_set_refresh_needed_after_insert - AFTER INSERT - ON species - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_species_set_refresh_needed_after_update - AFTER UPDATE - ON species - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_species_set_refresh_needed_after_delete - AFTER DELETE - ON species - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for quadrats -CREATE TRIGGER trg_quadrats_set_refresh_needed_after_insert - AFTER INSERT - ON quadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_quadrats_set_refresh_needed_after_update - AFTER UPDATE - ON quadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_quadrats_set_refresh_needed_after_delete - AFTER DELETE - ON quadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for census -CREATE TRIGGER trg_census_set_refresh_needed_after_insert - AFTER INSERT - ON census - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_census_set_refresh_needed_after_update - AFTER UPDATE - ON census - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_census_set_refresh_needed_after_delete - AFTER DELETE - ON census - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for cmattributes -CREATE TRIGGER trg_cmattributes_set_refresh_needed_after_insert - AFTER INSERT - ON cmattributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_cmattributes_set_refresh_needed_after_update - AFTER UPDATE - ON cmattributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_cmattributes_set_refresh_needed_after_delete - AFTER DELETE - ON cmattributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for plots -CREATE TRIGGER trg_plots_set_refresh_needed_after_insert - AFTER INSERT - ON plots - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_plots_set_refresh_needed_after_update - AFTER UPDATE - ON plots - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_plots_set_refresh_needed_after_delete - AFTER DELETE - ON plots - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for subquadrats -CREATE TRIGGER trg_subquadrats_set_refresh_needed_after_insert - AFTER INSERT - ON subquadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_subquadrats_set_refresh_needed_after_update - AFTER UPDATE - ON subquadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_subquadrats_set_refresh_needed_after_delete - AFTER DELETE - ON subquadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for roles -CREATE TRIGGER trg_roles_set_refresh_needed_after_insert - AFTER INSERT - ON roles - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_roles_set_refresh_needed_after_update - AFTER UPDATE - ON roles - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_roles_set_refresh_needed_after_delete - AFTER DELETE - ON roles - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for attributes -CREATE TRIGGER trg_attributes_set_refresh_needed_after_insert - AFTER INSERT - ON attributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_attributes_set_refresh_needed_after_update - AFTER UPDATE - ON attributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_attributes_set_refresh_needed_after_delete - AFTER DELETE - ON attributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for genus -CREATE TRIGGER trg_genus_set_refresh_needed_after_insert - AFTER INSERT - ON genus - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_genus_set_refresh_needed_after_update - AFTER UPDATE - ON genus - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_genus_set_refresh_needed_after_delete - AFTER DELETE - ON genus - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for family -CREATE TRIGGER trg_family_set_refresh_needed_after_insert - AFTER INSERT - ON family - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_family_set_refresh_needed_after_update - AFTER UPDATE - ON family - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_family_set_refresh_needed_after_delete - AFTER DELETE - ON family - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for specieslimits -CREATE TRIGGER trg_specieslimits_set_refresh_needed_after_insert - AFTER INSERT - ON specieslimits - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_specieslimits_set_refresh_needed_after_update - AFTER UPDATE - ON specieslimits - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_specieslimits_set_refresh_needed_after_delete - AFTER DELETE - ON specieslimits - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for quadratpersonnel -CREATE TRIGGER trg_quadratpersonnel_set_refresh_needed_after_insert - AFTER INSERT - ON quadratpersonnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_quadratpersonnel_set_refresh_needed_after_update - AFTER UPDATE - ON quadratpersonnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_quadratpersonnel_set_refresh_needed_after_delete - AFTER DELETE - ON quadratpersonnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for personnel -CREATE TRIGGER trg_personnel_set_refresh_needed_after_insert - AFTER INSERT - ON personnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_personnel_set_refresh_needed_after_update - AFTER UPDATE - ON personnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_personnel_set_refresh_needed_after_delete - AFTER DELETE - ON personnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_batchprocessingflag_before_insert - BEFORE INSERT - ON batchprocessingflag - FOR EACH ROW -BEGIN - IF NEW.flag_status = 'STARTED' THEN - -- Ensure there is only one STARTED flag and reset needs_refresh - DELETE FROM batchprocessingflag WHERE flag_status = 'STARTED'; - SET NEW.needs_refresh = FALSE; -END IF; -END; - -CREATE TRIGGER trg_batchprocessingflag_after_update - AFTER UPDATE - ON batchprocessingflag - FOR EACH ROW -BEGIN - IF NEW.flag_status = 'ENDED' AND NEW.needs_refresh = TRUE THEN - -- Call the refresh procedures - CALL RefreshMeasurementsSummary(); - CALL RefreshViewFullTable(); - - -- Reset the needs_refresh flag - UPDATE batchprocessingflag SET needs_refresh = FALSE WHERE flag_id = NEW.flag_id; -END IF; -END; - diff --git a/frontend/sqlscripting/materializedviews/measurementssummary/refresh.sql b/frontend/sqlscripting/materializedviews/measurementssummary/refresh.sql deleted file mode 100644 index 5b1516b5..00000000 --- a/frontend/sqlscripting/materializedviews/measurementssummary/refresh.sql +++ /dev/null @@ -1,39 +0,0 @@ -create -definer = azureroot@`%` procedure RefreshMeasurementsSummary() -BEGIN -TRUNCATE TABLE measurementssummary; -INSERT INTO measurementssummary -SELECT cm.CoreMeasurementID AS CoreMeasurementID, - st.StemID AS StemID, - t.TreeID AS TreeID, - s.SpeciesID AS SpeciesID, - q.QuadratID AS QuadratID, - q.PlotID AS PlotID, - cm.CensusID AS CensusID, - s.SpeciesName AS SpeciesName, - s.SubspeciesName AS SubspeciesName, - s.SpeciesCode AS SpeciesCode, - t.TreeTag AS TreeTag, - st.StemTag AS StemTag, - st.LocalX AS StemLocalX, - st.LocalY AS StemLocalY, - st.CoordinateUnits AS StemUnits, - q.QuadratName AS QuadratName, - cm.MeasurementDate AS MeasurementDate, - cm.MeasuredDBH AS MeasuredDBH, - cm.DBHUnit AS DBHUnits, - cm.MeasuredHOM AS MeasuredHOM, - cm.HOMUnit AS HOMUnits, - cm.IsValidated AS IsValidated, - cm.Description AS Description, - (SELECT GROUP_CONCAT(ca.Code SEPARATOR '; ') - FROM cmattributes ca - WHERE ca.CoreMeasurementID = cm.CoreMeasurementID) AS Attributes -FROM coremeasurements cm - LEFT JOIN stems st ON cm.StemID = st.StemID - LEFT JOIN trees t ON st.TreeID = t.TreeID - LEFT JOIN species s ON t.SpeciesID = s.SpeciesID - LEFT JOIN quadrats q ON st.QuadratID = q.QuadratID - LEFT JOIN census c ON cm.CensusID = c.CensusID; -END; - diff --git a/frontend/sqlscripting/materializedviews/measurementssummary/table.sql b/frontend/sqlscripting/materializedviews/measurementssummary/table.sql deleted file mode 100644 index fa1504f7..00000000 --- a/frontend/sqlscripting/materializedviews/measurementssummary/table.sql +++ /dev/null @@ -1,104 +0,0 @@ -CREATE TABLE IF NOT EXISTS measurementssummary -( - CoreMeasurementID - INT - PRIMARY - KEY, - StemID - INT, - TreeID - INT, - SpeciesID - INT, - QuadratID - INT, - PlotID - INT, - CensusID - INT, - SpeciesName - VARCHAR -( - 64 -), - SubspeciesName VARCHAR -( - 64 -), - SpeciesCode VARCHAR -( - 25 -), - TreeTag VARCHAR -( - 10 -), - StemTag VARCHAR -( - 10 -), - StemLocalX DECIMAL -( - 10, - 6 -), - StemLocalY DECIMAL -( - 10, - 6 -), - StemUnits ENUM -( - 'km', - 'hm', - 'dam', - 'm', - 'dm', - 'cm', - 'mm' -) DEFAULT 'm', - QuadratName VARCHAR -( - 255 -), - MeasurementDate DATE, - MeasuredDBH DECIMAL -( - 10, - 6 -), - DBHUnits ENUM -( - 'km', - 'hm', - 'dam', - 'm', - 'dm', - 'cm', - 'mm' -) DEFAULT 'cm', - MeasuredHOM DECIMAL -( - 10, - 6 -), - HOMUnits ENUM -( - 'km', - 'hm', - 'dam', - 'm', - 'dm', - 'cm', - 'mm' -) DEFAULT 'm', - IsValidated BIT DEFAULT b'0', - Description VARCHAR -( - 255 -), - Attributes VARCHAR -( - 255 -) - ); \ No newline at end of file diff --git a/frontend/sqlscripting/materializedviews/viewfulltable/refresh.sql b/frontend/sqlscripting/materializedviews/viewfulltable/refresh.sql deleted file mode 100644 index 7e6f46e8..00000000 --- a/frontend/sqlscripting/materializedviews/viewfulltable/refresh.sql +++ /dev/null @@ -1,169 +0,0 @@ -create -definer = azureroot@`%` procedure RefreshViewFullTable() -BEGIN - -- Truncate the materialized table -TRUNCATE TABLE viewfulltable; - --- Insert data from the view into the materialized table -INSERT INTO viewfulltable (CoreMeasurementID, - MeasurementDate, - MeasuredDBH, - DBHUnits, - MeasuredHOM, - HOMUnits, - Description, - IsValidated, - PlotID, - PlotName, - LocationName, - CountryName, - DimensionX, - DimensionY, - PlotDimensionUnits, - PlotArea, - PlotAreaUnits, - PlotGlobalX, - PlotGlobalY, - PlotGlobalZ, - PlotCoordinateUnits, - PlotShape, - PlotDescription, - CensusID, - CensusStartDate, - CensusEndDate, - CensusDescription, - PlotCensusNumber, - QuadratID, - QuadratName, - QuadratDimensionX, - QuadratDimensionY, - QuadratDimensionUnits, - QuadratArea, - QuadratAreaUnits, - QuadratStartX, - QuadratStartY, - QuadratCoordinateUnits, - QuadratShape, - SubquadratID, - SubquadratName, - SubquadratDimensionX, - SubquadratDimensionY, - SubquadratDimensionUnits, - SubquadratX, - SubquadratY, - SubquadratCoordinateUnits, - TreeID, - TreeTag, - StemID, - StemTag, - StemLocalX, - StemLocalY, - StemCoordinateUnits, - PersonnelID, - FirstName, - LastName, - PersonnelRoles, - SpeciesID, - SpeciesCode, - SpeciesName, - SubspeciesName, - SubspeciesAuthority, - SpeciesIDLevel, - GenusID, - Genus, - GenusAuthority, - FamilyID, - Family, - AttributeCode, - AttributeDescription, - AttributeStatus) -SELECT cm.CoreMeasurementID, - cm.MeasurementDate, - cm.MeasuredDBH, - cm.DBHUnit, - cm.MeasuredHOM, - cm.HOMUnit, - cm.Description, - cm.IsValidated, - p.PlotID, - p.PlotName, - p.LocationName, - p.CountryName, - p.DimensionX, - p.DimensionY, - p.DimensionUnits, - p.Area, - p.AreaUnits, - p.GlobalX, - p.GlobalY, - p.GlobalZ, - p.CoordinateUnits, - p.PlotShape, - p.PlotDescription, - c.CensusID, - c.StartDate, - c.EndDate, - c.Description, - c.PlotCensusNumber, - q.QuadratID, - q.QuadratName, - q.DimensionX, - q.DimensionY, - q.DimensionUnits, - q.Area, - q.AreaUnits, - q.StartX, - q.StartY, - q.CoordinateUnits, - q.QuadratShape, - sq.SubquadratID, - sq.SubquadratName, - sq.DimensionX, - sq.DimensionY, - sq.DimensionUnits, - sq.QX, - sq.QY, - sq.CoordinateUnits, - t.TreeID, - t.TreeTag, - s.StemID, - s.StemTag, - s.LocalX, - s.LocalY, - s.CoordinateUnits, - per.PersonnelID, - per.FirstName, - per.LastName, - r.RoleName, - sp.SpeciesID, - sp.SpeciesCode, - sp.SpeciesName, - sp.SubspeciesName, - sp.SubspeciesAuthority, - sp.IDLevel, - g.GenusID, - g.Genus, - g.GenusAuthority, - fam.FamilyID, - fam.Family, - attr.Code, - attr.Description, - attr.Status -FROM coremeasurements cm - LEFT JOIN stems s ON cm.StemID = s.StemID - LEFT JOIN trees t ON s.TreeID = t.TreeID - LEFT JOIN species sp ON t.SpeciesID = sp.SpeciesID - LEFT JOIN genus g ON sp.GenusID = g.GenusID - LEFT JOIN family fam ON g.FamilyID = fam.FamilyID - LEFT JOIN specieslimits sl ON sp.SpeciesCode = sl.SpeciesCode - LEFT JOIN quadrats q ON s.QuadratID = q.QuadratID - LEFT JOIN quadratpersonnel qp ON q.QuadratID = qp.QuadratID - LEFT JOIN personnel per ON qp.PersonnelID = per.PersonnelID - LEFT JOIN plots p ON q.PlotID = p.PlotID - LEFT JOIN subquadrats sq ON q.QuadratID = sq.QuadratID - LEFT JOIN census c ON cm.CensusID = c.CensusID - LEFT JOIN roles r ON per.RoleID = r.RoleID - LEFT JOIN cmattributes cma ON cm.CoreMeasurementID = cma.CoreMeasurementID - LEFT JOIN attributes attr ON cma.Code = attr.Code; -END; - diff --git a/frontend/sqlscripting/materializedviews/viewfulltable/table.sql b/frontend/sqlscripting/materializedviews/viewfulltable/table.sql deleted file mode 100644 index f0868f2a..00000000 --- a/frontend/sqlscripting/materializedviews/viewfulltable/table.sql +++ /dev/null @@ -1,307 +0,0 @@ -CREATE TABLE IF NOT EXISTS viewfulltable -( - CoreMeasurementID - INT - PRIMARY - KEY, - MeasurementDate - DATE, - MeasuredDBH - DECIMAL -( - 10, - 6 -), - DBHUnits ENUM -( - 'km', - 'hm', - 'dam', - 'm', - 'dm', - 'cm', - 'mm' -) DEFAULT 'cm', - MeasuredHOM DECIMAL -( - 10, - 6 -), - HOMUnits ENUM -( - 'km', - 'hm', - 'dam', - 'm', - 'dm', - 'cm', - 'mm' -) DEFAULT 'm', - Description VARCHAR -( - 255 -), - IsValidated BIT DEFAULT b'0', - PlotID INT, - PlotName VARCHAR -( - 255 -), - LocationName VARCHAR -( - 255 -), - CountryName VARCHAR -( - 255 -), - DimensionX INT, - DimensionY INT, - PlotDimensionUnits ENUM -( - 'km', - 'hm', - 'dam', - 'm', - 'dm', - 'cm', - 'mm' -) DEFAULT 'm', - PlotArea DECIMAL -( - 10, - 6 -), - PlotAreaUnits ENUM -( - 'km2', - 'hm2', - 'dam2', - 'm2', - 'dm2', - 'cm2', - 'mm2' -) DEFAULT 'm2', - PlotGlobalX DECIMAL -( - 10, - 6 -), - PlotGlobalY DECIMAL -( - 10, - 6 -), - PlotGlobalZ DECIMAL -( - 10, - 6 -), - PlotCoordinateUnits ENUM -( - 'km', - 'hm', - 'dam', - 'm', - 'dm', - 'cm', - 'mm' -) DEFAULT 'm', - PlotShape VARCHAR -( - 255 -), - PlotDescription VARCHAR -( - 255 -), - CensusID INT, - CensusStartDate DATE, - CensusEndDate DATE, - CensusDescription VARCHAR -( - 255 -), - PlotCensusNumber INT, - QuadratID INT, - QuadratName VARCHAR -( - 255 -), - QuadratDimensionX INT, - QuadratDimensionY INT, - QuadratDimensionUnits ENUM -( - 'km', - 'hm', - 'dam', - 'm', - 'dm', - 'cm', - 'mm' -) DEFAULT 'm', - QuadratArea DECIMAL -( - 10, - 6 -), - QuadratAreaUnits ENUM -( - 'km2', - 'hm2', - 'dam2', - 'm2', - 'dm2', - 'cm2', - 'mm2' -) DEFAULT 'm2', - QuadratStartX DECIMAL -( - 10, - 6 -), - QuadratStartY DECIMAL -( - 10, - 6 -), - QuadratCoordinateUnits ENUM -( - 'km', - 'hm', - 'dam', - 'm', - 'dm', - 'cm', - 'mm' -) DEFAULT 'm', - QuadratShape VARCHAR -( - 255 -), - SubquadratID INT, - SubquadratName VARCHAR -( - 255 -), - SubquadratDimensionX INT, - SubquadratDimensionY INT, - SubquadratDimensionUnits ENUM -( - 'km', - 'hm', - 'dam', - 'm', - 'dm', - 'cm', - 'mm' -) DEFAULT 'm', - SubquadratX INT, - SubquadratY INT, - SubquadratCoordinateUnits ENUM -( - 'km', - 'hm', - 'dam', - 'm', - 'dm', - 'cm', - 'mm' -) DEFAULT 'm', - TreeID INT, - TreeTag VARCHAR -( - 10 -), - StemID INT, - StemTag VARCHAR -( - 10 -), - StemLocalX DECIMAL -( - 10, - 6 -), - StemLocalY DECIMAL -( - 10, - 6 -), - StemCoordinateUnits ENUM -( - 'km', - 'hm', - 'dam', - 'm', - 'dm', - 'cm', - 'mm' -) DEFAULT 'm', - PersonnelID INT, - FirstName VARCHAR -( - 50 -), - LastName VARCHAR -( - 50 -), - PersonnelRoles VARCHAR -( - 255 -), - SpeciesID INT, - SpeciesCode VARCHAR -( - 25 -), - SpeciesName VARCHAR -( - 64 -), - SubspeciesName VARCHAR -( - 64 -), - SubspeciesAuthority VARCHAR -( - 128 -), - SpeciesIDLevel VARCHAR -( - 20 -), - GenusID INT, - Genus VARCHAR -( - 32 -), - GenusAuthority VARCHAR -( - 32 -), - FamilyID INT, - Family VARCHAR -( - 32 -), - AttributeCode VARCHAR -( - 10 -), - AttributeDescription VARCHAR -( - 255 -), - AttributeStatus ENUM -( - 'alive', - 'alive-not measured', - 'dead', - 'stem dead', - 'broken below', - 'omitted', - 'missing' -) DEFAULT 'alive' - ); diff --git a/frontend/sqlscripting/materializedviewtriggers.sql b/frontend/sqlscripting/materializedviewtriggers.sql deleted file mode 100644 index d0a5433c..00000000 --- a/frontend/sqlscripting/materializedviewtriggers.sql +++ /dev/null @@ -1,427 +0,0 @@ --- Create triggers for coremeasurements -CREATE TRIGGER trg_coremeasurements_set_refresh_needed_after_insert - AFTER INSERT - ON coremeasurements - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_coremeasurements_set_refresh_needed_after_update - AFTER UPDATE - ON coremeasurements - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_coremeasurements_set_refresh_needed_after_delete - AFTER DELETE - ON coremeasurements - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for stems -CREATE TRIGGER trg_stems_set_refresh_needed_after_insert - AFTER INSERT - ON stems - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_stems_set_refresh_needed_after_update - AFTER UPDATE - ON stems - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_stems_set_refresh_needed_after_delete - AFTER DELETE - ON stems - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for trees -CREATE TRIGGER trg_trees_set_refresh_needed_after_insert - AFTER INSERT - ON trees - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_trees_set_refresh_needed_after_update - AFTER UPDATE - ON trees - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_trees_set_refresh_needed_after_delete - AFTER DELETE - ON trees - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for species -CREATE TRIGGER trg_species_set_refresh_needed_after_insert - AFTER INSERT - ON species - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_species_set_refresh_needed_after_update - AFTER UPDATE - ON species - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_species_set_refresh_needed_after_delete - AFTER DELETE - ON species - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for quadrats -CREATE TRIGGER trg_quadrats_set_refresh_needed_after_insert - AFTER INSERT - ON quadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_quadrats_set_refresh_needed_after_update - AFTER UPDATE - ON quadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_quadrats_set_refresh_needed_after_delete - AFTER DELETE - ON quadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for census -CREATE TRIGGER trg_census_set_refresh_needed_after_insert - AFTER INSERT - ON census - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_census_set_refresh_needed_after_update - AFTER UPDATE - ON census - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_census_set_refresh_needed_after_delete - AFTER DELETE - ON census - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for cmattributes -CREATE TRIGGER trg_cmattributes_set_refresh_needed_after_insert - AFTER INSERT - ON cmattributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_cmattributes_set_refresh_needed_after_update - AFTER UPDATE - ON cmattributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_cmattributes_set_refresh_needed_after_delete - AFTER DELETE - ON cmattributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for plots -CREATE TRIGGER trg_plots_set_refresh_needed_after_insert - AFTER INSERT - ON plots - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_plots_set_refresh_needed_after_update - AFTER UPDATE - ON plots - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_plots_set_refresh_needed_after_delete - AFTER DELETE - ON plots - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for subquadrats -CREATE TRIGGER trg_subquadrats_set_refresh_needed_after_insert - AFTER INSERT - ON subquadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_subquadrats_set_refresh_needed_after_update - AFTER UPDATE - ON subquadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_subquadrats_set_refresh_needed_after_delete - AFTER DELETE - ON subquadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for roles -CREATE TRIGGER trg_roles_set_refresh_needed_after_insert - AFTER INSERT - ON roles - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_roles_set_refresh_needed_after_update - AFTER UPDATE - ON roles - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_roles_set_refresh_needed_after_delete - AFTER DELETE - ON roles - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for attributes -CREATE TRIGGER trg_attributes_set_refresh_needed_after_insert - AFTER INSERT - ON attributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_attributes_set_refresh_needed_after_update - AFTER UPDATE - ON attributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_attributes_set_refresh_needed_after_delete - AFTER DELETE - ON attributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for genus -CREATE TRIGGER trg_genus_set_refresh_needed_after_insert - AFTER INSERT - ON genus - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_genus_set_refresh_needed_after_update - AFTER UPDATE - ON genus - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_genus_set_refresh_needed_after_delete - AFTER DELETE - ON genus - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for family -CREATE TRIGGER trg_family_set_refresh_needed_after_insert - AFTER INSERT - ON family - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_family_set_refresh_needed_after_update - AFTER UPDATE - ON family - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_family_set_refresh_needed_after_delete - AFTER DELETE - ON family - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for specieslimits -CREATE TRIGGER trg_specieslimits_set_refresh_needed_after_insert - AFTER INSERT - ON specieslimits - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_specieslimits_set_refresh_needed_after_update - AFTER UPDATE - ON specieslimits - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_specieslimits_set_refresh_needed_after_delete - AFTER DELETE - ON specieslimits - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for quadratpersonnel -CREATE TRIGGER trg_quadratpersonnel_set_refresh_needed_after_insert - AFTER INSERT - ON quadratpersonnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_quadratpersonnel_set_refresh_needed_after_update - AFTER UPDATE - ON quadratpersonnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_quadratpersonnel_set_refresh_needed_after_delete - AFTER DELETE - ON quadratpersonnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for personnel -CREATE TRIGGER trg_personnel_set_refresh_needed_after_insert - AFTER INSERT - ON personnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_personnel_set_refresh_needed_after_update - AFTER UPDATE - ON personnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_personnel_set_refresh_needed_after_delete - AFTER DELETE - ON personnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_batchprocessingflag_before_insert - BEFORE INSERT - ON batchprocessingflag - FOR EACH ROW -BEGIN - IF NEW.flag_status = 'STARTED' THEN - -- Ensure there is only one STARTED flag and reset needs_refresh - DELETE FROM batchprocessingflag WHERE flag_status = 'STARTED'; - SET NEW.needs_refresh = FALSE; -END IF; -END; - -CREATE TRIGGER trg_batchprocessingflag_after_update - AFTER UPDATE - ON batchprocessingflag - FOR EACH ROW -BEGIN - IF NEW.flag_status = 'ENDED' AND NEW.needs_refresh = TRUE THEN - -- Call the refresh procedures - CALL RefreshMeasurementsSummary(); - CALL RefreshViewFullTable(); - - -- Reset the needs_refresh flag - UPDATE batchprocessingflag SET needs_refresh = FALSE WHERE flag_id = NEW.flag_id; -END IF; -END; - diff --git a/frontend/sqlscripting/migration-OoO/1-resetexistingschema.sql b/frontend/sqlscripting/migration-OoO/1-resetexistingschema.sql deleted file mode 100644 index d013d0d7..00000000 --- a/frontend/sqlscripting/migration-OoO/1-resetexistingschema.sql +++ /dev/null @@ -1,532 +0,0 @@ -SET -foreign_key_checks = 0; -drop table if exists attributes; -drop table if exists census; -drop table if exists cmattributes; -drop table if exists cmverrors; -drop table if exists coremeasurements; -drop table if exists family; -drop table if exists genus; -drop table if exists personnel; -drop table if exists plots; -drop table if exists quadratpersonnel; -drop table if exists quadrats; -drop table if exists reference; -drop table if exists roles; -drop table if exists species; -drop table if exists specieslimits; -drop table if exists specimens; -drop table if exists stems; -drop table if exists trees; -drop table if exists subquadrats; -drop table if exists unifiedchangelog; -drop table if exists validationchangelog; - -# -materialized view tables -drop table if exists measurementssummary; -drop table if exists viewfulltable; - -DROP VIEW IF EXISTS `alltaxonomiesview`; -DROP VIEW IF EXISTS `measurementssummaryview`; -DROP VIEW IF EXISTS `stemtaxonomiesview`; -DROP VIEW IF EXISTS `viewfulltableview`; - -DROP PROCEDURE IF EXISTS RefreshMeasurementsSummary; -DROP PROCEDURE IF EXISTS RefreshViewFullTable; -DROP PROCEDURE IF EXISTS `UpdateValidationStatus`; -DROP PROCEDURE IF EXISTS `ValidateDBHGrowthExceedsMax`; -DROP PROCEDURE IF EXISTS `ValidateDBHShrinkageExceedsMax`; -DROP PROCEDURE IF EXISTS `ValidateFindAllInvalidSpeciesCodes`; -DROP PROCEDURE IF EXISTS `ValidateFindDuplicatedQuadratsByName`; -DROP PROCEDURE IF EXISTS `ValidateFindDuplicateStemTreeTagCombinationsPerCensus`; -DROP PROCEDURE IF EXISTS `ValidateFindMeasurementsOutsideCensusDateBoundsGroupByQuadrat`; -DROP PROCEDURE IF EXISTS `ValidateFindStemsInTreeWithDifferentSpecies`; -DROP PROCEDURE IF EXISTS `ValidateFindStemsOutsidePlots`; -DROP PROCEDURE IF EXISTS `ValidateFindTreeStemsInDifferentQuadrats`; -DROP PROCEDURE IF EXISTS `ValidateHOMUpperAndLowerBounds`; -DROP PROCEDURE IF EXISTS `ValidateScreenMeasuredDiameterMinMax`; -DROP PROCEDURE IF EXISTS `ValidateScreenStemsWithMeasurementsButDeadAttributes`; - -create table attributes -( - Code varchar(10) not null - primary key, - Description varchar(255) null, - Status enum ('alive', 'alive-not measured', 'dead', 'stem dead', 'broken below', 'omitted', 'missing') default 'alive' null -); - -create table measurementssummary -( - CoreMeasurementID int not null - primary key, - StemID int null, - TreeID int null, - SpeciesID int null, - QuadratID int null, - PlotID int null, - CensusID int null, - SpeciesName varchar(64) null, - SubspeciesName varchar(64) null, - SpeciesCode varchar(25) null, - TreeTag varchar(10) null, - StemTag varchar(10) null, - StemLocalX decimal(10, 6) null, - StemLocalY decimal(10, 6) null, - StemUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - QuadratName varchar(255) null, - MeasurementDate date null, - MeasuredDBH decimal(10, 6) null, - DBHUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'cm' null, - MeasuredHOM decimal(10, 6) null, - HOMUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - IsValidated bit default b'0' null, - Description varchar(255) null, - Attributes varchar(255) null -); - -create table plots -( - PlotID int auto_increment - primary key, - PlotName varchar(255) null, - LocationName varchar(255) null, - CountryName varchar(255) null, - DimensionX int null, - DimensionY int null, - DimensionUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - Area decimal(10, 6) null, - AreaUnits enum ('km2', 'hm2', 'dam2', 'm2', 'dm2', 'cm2', 'mm2') default 'm2' null, - GlobalX decimal(10, 6) null, - GlobalY decimal(10, 6) null, - GlobalZ decimal(10, 6) null, - CoordinateUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - PlotShape varchar(255) null, - PlotDescription varchar(255) null -); - -create table census -( - CensusID int auto_increment - primary key, - PlotID int null, - StartDate date null, - EndDate date null, - Description varchar(255) null, - PlotCensusNumber int null, - constraint Census_Plots_PlotID_fk - foreign key (PlotID) references plots (PlotID) -); - -create table quadrats -( - QuadratID int auto_increment - primary key, - PlotID int null, - CensusID int null, - QuadratName varchar(255) null, - StartX decimal(10, 6) null, - StartY decimal(10, 6) null, - CoordinateUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - DimensionX int null, - DimensionY int null, - DimensionUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - Area decimal(10, 6) null, - AreaUnits enum ('km2', 'hm2', 'dam2', 'm2', 'dm2', 'cm2', 'mm2') default 'm2' null, - QuadratShape varchar(255) null, - constraint unique_quadrat_name_per_census_plot - unique (CensusID, PlotID, QuadratName), - constraint Quadrats_Plots_FK - foreign key (PlotID) references plots (PlotID), - constraint quadrats_census_CensusID_fk - foreign key (CensusID) references census (CensusID) -); - -create index idx_censusid_quadrats - on quadrats (CensusID); - -create index idx_pid_cid_quadrats - on quadrats (PlotID, CensusID); - -create index idx_plotid_quadrats - on quadrats (PlotID); - -create index idx_qid_pid_cid_quadrats - on quadrats (QuadratID, PlotID, CensusID); - -create index idx_qid_pid_quadrats - on quadrats (QuadratID, PlotID); - -create index idx_quadratid_quadrats - on quadrats (QuadratID); - -create table reference -( - ReferenceID int auto_increment - primary key, - PublicationTitle varchar(64) null, - FullReference varchar(255) null, - DateOfPublication date null, - Citation varchar(50) null -); - -create table family -( - FamilyID int auto_increment - primary key, - Family varchar(32) null, - ReferenceID int null, - constraint Family - unique (Family), - constraint Family_Reference_ReferenceID_fk - foreign key (ReferenceID) references reference (ReferenceID) -); - -create table genus -( - GenusID int auto_increment - primary key, - FamilyID int null, - Genus varchar(32) null, - ReferenceID int null, - GenusAuthority varchar(32) null, - constraint Genus - unique (Genus), - constraint Genus_Family_FamilyID_fk - foreign key (FamilyID) references family (FamilyID), - constraint Genus_Reference_ReferenceID_fk - foreign key (ReferenceID) references reference (ReferenceID) -); - -create table roles -( - RoleID int auto_increment - primary key, - RoleName varchar(255) null, - RoleDescription varchar(255) null -); - -create table personnel -( - PersonnelID int auto_increment - primary key, - CensusID int null, - FirstName varchar(50) null, - LastName varchar(50) null, - RoleID int null, - constraint unique_full_name_per_census - unique (CensusID, FirstName, LastName), - constraint personnel_census_CensusID_fk - foreign key (CensusID) references census (CensusID), - constraint personnel_roles_RoleID_fk - foreign key (RoleID) references roles (RoleID) -); - -create table quadratpersonnel -( - QuadratPersonnelID int auto_increment - primary key, - QuadratID int not null, - PersonnelID int not null, - CensusID int null, - constraint fk_QuadratPersonnel_Personnel - foreign key (PersonnelID) references personnel (PersonnelID), - constraint fk_QuadratPersonnel_Quadrats - foreign key (QuadratID) references quadrats (QuadratID), - constraint quadratpersonnel_census_CensusID_fk - foreign key (CensusID) references census (CensusID) -); - -create table species -( - SpeciesID int auto_increment - primary key, - GenusID int null, - SpeciesCode varchar(25) null, - SpeciesName varchar(64) null, - SubspeciesName varchar(64) null, - IDLevel varchar(20) null, - SpeciesAuthority varchar(128) null, - SubspeciesAuthority varchar(128) null, - FieldFamily varchar(32) null, - Description varchar(255) null, - ValidCode varchar(255) null, - ReferenceID int null, - constraint SpeciesCode - unique (SpeciesCode), - constraint Species_SpeciesCode - unique (SpeciesCode), - constraint Species_Genus_GenusID_fk - foreign key (GenusID) references genus (GenusID), - constraint Species_Reference_ReferenceID_fk - foreign key (ReferenceID) references reference (ReferenceID) -); - -create table specieslimits -( - SpeciesLimitID int auto_increment - primary key, - SpeciesCode varchar(25) null, - LimitType enum ('DBH') null, - UpperBound decimal(10, 6) null, - LowerBound decimal(10, 6) null, - Unit enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'cm' null, - constraint specieslimits_ibfk_1 - foreign key (SpeciesCode) references species (SpeciesCode) -); - -create table subquadrats -( - SubquadratID int auto_increment - primary key, - SubquadratName varchar(25) null, - QuadratID int null, - DimensionX int default 5 null, - DimensionY int default 5 null, - DimensionUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - QX int null, - QY int null, - CoordinateUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - Ordering int null, - constraint SQName - unique (SubquadratName), - constraint subquadrats_ibfk_1 - foreign key (QuadratID) references quadrats (QuadratID) -); - -create table trees -( - TreeID int auto_increment - primary key, - TreeTag varchar(10) null, - SpeciesID int null, - constraint TreeTag - unique (TreeTag), - constraint Trees_Species_SpeciesID_fk - foreign key (SpeciesID) references species (SpeciesID) -); - -create table stems -( - StemID int auto_increment - primary key, - TreeID int null, - QuadratID int null, - StemNumber int null, - StemTag varchar(10) null, - LocalX decimal(10, 6) null, - LocalY decimal(10, 6) null, - CoordinateUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - Moved bit null, - StemDescription varchar(255) null, - constraint FK_Stems_Trees - foreign key (TreeID) references trees (TreeID), - constraint stems_quadrats_QuadratID_fk - foreign key (QuadratID) references quadrats (QuadratID) -); - -create table coremeasurements -( - CoreMeasurementID int auto_increment - primary key, - CensusID int null, - StemID int null, - IsValidated bit default b'0' null, - MeasurementDate date null, - MeasuredDBH decimal(10, 6) null, - DBHUnit enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'cm' null, - MeasuredHOM decimal(10, 6) null, - HOMUnit enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - Description varchar(255) null, - UserDefinedFields text null, - constraint FK_CoreMeasurements_Stems - foreign key (StemID) references stems (StemID), - constraint coremeasurements_census_CensusID_fk - foreign key (CensusID) references census (CensusID) -); - -create table cmattributes -( - CMAID int auto_increment - primary key, - CoreMeasurementID int null, - Code varchar(10) null, - constraint CMAttributes_Attributes_Code_fk - foreign key (Code) references attributes (Code), - constraint CMAttributes_CoreMeasurements_CoreMeasurementID_fk - foreign key (CoreMeasurementID) references coremeasurements (CoreMeasurementID) -); - -create table cmverrors -( - CMVErrorID int auto_increment - primary key, - CoreMeasurementID int null, - ValidationErrorID int null, - constraint cmverrors_coremeasurements_CoreMeasurementID_fk - foreign key (CoreMeasurementID) references coremeasurements (CoreMeasurementID), - constraint cmverrors_validationprocedures_ValidationID_fk - foreign key (ValidationErrorID) references catalog.validationprocedures (ValidationID) -); - -create index idx_censusid_coremeasurements - on coremeasurements (CensusID); - -create index idx_cmid_cid_coremeasurements - on coremeasurements (CoreMeasurementID, CensusID); - -create index idx_cmid_cid_sid_coremeasurements - on coremeasurements (CoreMeasurementID, CensusID, StemID); - -create index idx_coremeasurementid_coremeasurements - on coremeasurements (CoreMeasurementID); - -create index idx_measurementdate_coremeasurements - on coremeasurements (MeasurementDate); - -create index idx_stemid_coremeasurements - on coremeasurements (StemID); - -create table specimens -( - SpecimenID int auto_increment - primary key, - StemID int null, - PersonnelID int null, - SpecimenNumber int null, - SpeciesID int null, - Herbarium varchar(32) null, - Voucher smallint unsigned null, - CollectionDate date null, - DeterminedBy varchar(64) null, - Description varchar(255) null, - constraint specimens_personnel_PersonnelID_fk - foreign key (PersonnelID) references personnel (PersonnelID), - constraint specimens_stems_StemID_fk - foreign key (StemID) references stems (StemID) -); - -create index idx_quadratid_stems - on stems (QuadratID); - -create index idx_sid_tid_qid_stems - on stems (StemID, TreeID, QuadratID); - -create index idx_stemid_stems - on stems (StemID); - -create index idx_stemid_treeid_stems - on stems (StemID, TreeID); - -create index idx_treeid_stems - on stems (TreeID); - -create table unifiedchangelog -( - ChangeID int auto_increment, - TableName varchar(64) not null, - RecordID varchar(255) not null, - Operation enum ('INSERT', 'UPDATE', 'DELETE') not null, - OldRowState json null, - NewRowState json null, - ChangeTimestamp datetime default CURRENT_TIMESTAMP null, - ChangedBy varchar(64) null, - primary key (ChangeID, TableName) -) partition by key (`TableName`) partitions 24; - -create table validationchangelog -( - ValidationRunID int auto_increment - primary key, - ProcedureName varchar(255) not null, - RunDateTime datetime default CURRENT_TIMESTAMP not null, - TargetRowID int null, - ValidationOutcome enum ('Passed', 'Failed') null, - ErrorMessage varchar(255) null, - ValidationCriteria varchar(255) null, - MeasuredValue varchar(255) null, - ExpectedValueRange varchar(255) null, - AdditionalDetails varchar(255) null -); - -create table viewfulltable -( - CoreMeasurementID int not null - primary key, - MeasurementDate date null, - MeasuredDBH decimal(10, 6) null, - DBHUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'cm' null, - MeasuredHOM decimal(10, 6) null, - HOMUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - Description varchar(255) null, - IsValidated bit default b'0' null, - PlotID int null, - PlotName varchar(255) null, - LocationName varchar(255) null, - CountryName varchar(255) null, - DimensionX int null, - DimensionY int null, - PlotDimensionUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - PlotArea decimal(10, 6) null, - PlotAreaUnits enum ('km2', 'hm2', 'dam2', 'm2', 'dm2', 'cm2', 'mm2') default 'm2' null, - PlotGlobalX decimal(10, 6) null, - PlotGlobalY decimal(10, 6) null, - PlotGlobalZ decimal(10, 6) null, - PlotCoordinateUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - PlotShape varchar(255) null, - PlotDescription varchar(255) null, - CensusID int null, - CensusStartDate date null, - CensusEndDate date null, - CensusDescription varchar(255) null, - PlotCensusNumber int null, - QuadratID int null, - QuadratName varchar(255) null, - QuadratDimensionX int null, - QuadratDimensionY int null, - QuadratDimensionUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - QuadratArea decimal(10, 6) null, - QuadratAreaUnits enum ('km2', 'hm2', 'dam2', 'm2', 'dm2', 'cm2', 'mm2') default 'm2' null, - QuadratStartX decimal(10, 6) null, - QuadratStartY decimal(10, 6) null, - QuadratCoordinateUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - QuadratShape varchar(255) null, - SubquadratID int null, - SubquadratName varchar(255) null, - SubquadratDimensionX int null, - SubquadratDimensionY int null, - SubquadratDimensionUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - SubquadratX int null, - SubquadratY int null, - SubquadratCoordinateUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - TreeID int null, - TreeTag varchar(10) null, - StemID int null, - StemTag varchar(10) null, - StemLocalX decimal(10, 6) null, - StemLocalY decimal(10, 6) null, - StemCoordinateUnits enum ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') default 'm' null, - PersonnelID int null, - FirstName varchar(50) null, - LastName varchar(50) null, - PersonnelRoles varchar(255) null, - SpeciesID int null, - SpeciesCode varchar(25) null, - SpeciesName varchar(64) null, - SubspeciesName varchar(64) null, - SubspeciesAuthority varchar(128) null, - SpeciesIDLevel varchar(20) null, - GenusID int null, - Genus varchar(32) null, - GenusAuthority varchar(32) null, - FamilyID int null, - Family varchar(32) null, - AttributeCode varchar(10) null, - AttributeDescription varchar(255) null, - AttributeStatus enum ('alive', 'alive-not measured', 'dead', 'stem dead', 'broken below', 'omitted', 'missing') default 'alive' null -); - - - -set -foreign_key_checks = 1; \ No newline at end of file diff --git a/frontend/sqlscripting/migration-OoO/2-clearchangelogtriggers.sql b/frontend/sqlscripting/migration-OoO/2-clearchangelogtriggers.sql deleted file mode 100644 index a0b1e756..00000000 --- a/frontend/sqlscripting/migration-OoO/2-clearchangelogtriggers.sql +++ /dev/null @@ -1,119 +0,0 @@ -# -attributes -DROP TRIGGER IF EXISTS after_insert_attributes; -DROP TRIGGER IF EXISTS after_update_attributes; -DROP TRIGGER IF EXISTS after_delete_attributes; - -# -census -DROP TRIGGER IF EXISTS after_insert_census; -DROP TRIGGER IF EXISTS after_update_census; -DROP TRIGGER IF EXISTS after_delete_census; - -# -cmattributes -DROP TRIGGER IF EXISTS after_insert_cmattributes; -DROP TRIGGER IF EXISTS after_update_cmattributes; -DROP TRIGGER IF EXISTS after_delete_cmattributes; - -# -cmverrors -DROP TRIGGER IF EXISTS after_insert_cmverrors; -DROP TRIGGER IF EXISTS after_update_cmverrors; -DROP TRIGGER IF EXISTS after_delete_cmverrors; - -# -coremeasurements -DROP TRIGGER IF EXISTS after_insert_coremeasurements; -DROP TRIGGER IF EXISTS after_update_coremeasurements; -DROP TRIGGER IF EXISTS after_delete_coremeasurements; - -# -family -DROP TRIGGER IF EXISTS after_insert_family; -DROP TRIGGER IF EXISTS after_update_family; -DROP TRIGGER IF EXISTS after_delete_family; - -# -genus -DROP TRIGGER IF EXISTS after_insert_genus; -DROP TRIGGER IF EXISTS after_update_genus; -DROP TRIGGER IF EXISTS after_delete_genus; - -# -personnel -DROP TRIGGER IF EXISTS after_insert_personnel; -DROP TRIGGER IF EXISTS after_update_personnel; -DROP TRIGGER IF EXISTS after_delete_personnel; - -# -plots -DROP TRIGGER IF EXISTS after_insert_plots; -DROP TRIGGER IF EXISTS after_update_plots; -DROP TRIGGER IF EXISTS after_delete_plots; - -# -quadratpersonnel -DROP TRIGGER IF EXISTS after_insert_quadratpersonnel; -DROP TRIGGER IF EXISTS after_update_quadratpersonnel; -DROP TRIGGER IF EXISTS after_delete_quadratpersonnel; - -# -quadrats -DROP TRIGGER IF EXISTS after_insert_quadrats; -DROP TRIGGER IF EXISTS after_update_quadrats; -DROP TRIGGER IF EXISTS after_delete_quadrats; - -# -reference -DROP TRIGGER IF EXISTS after_insert_reference; -DROP TRIGGER IF EXISTS after_update_reference; -DROP TRIGGER IF EXISTS after_delete_reference; - -# -roles -DROP TRIGGER IF EXISTS after_insert_roles; -DROP TRIGGER IF EXISTS after_update_roles; -DROP TRIGGER IF EXISTS after_delete_roles; - -# -species -DROP TRIGGER IF EXISTS after_insert_species; -DROP TRIGGER IF EXISTS after_update_species; -DROP TRIGGER IF EXISTS after_delete_species; - -# -specieslimits -DROP TRIGGER IF EXISTS after_insert_specieslimits; -DROP TRIGGER IF EXISTS after_update_specieslimits; -DROP TRIGGER IF EXISTS after_delete_specieslimits; - -# -specimens -DROP TRIGGER IF EXISTS after_insert_specimens; -DROP TRIGGER IF EXISTS after_update_specimens; -DROP TRIGGER IF EXISTS after_delete_specimens; - -# -stems -DROP TRIGGER IF EXISTS after_insert_stems; -DROP TRIGGER IF EXISTS after_update_stems; -DROP TRIGGER IF EXISTS after_delete_stems; - -# -subquadrats -DROP TRIGGER IF EXISTS after_insert_subquadrats; -DROP TRIGGER IF EXISTS after_update_subquadrats; -DROP TRIGGER IF EXISTS after_delete_subquadrats; - -# -trees -DROP TRIGGER IF EXISTS after_insert_trees; -DROP TRIGGER IF EXISTS after_update_trees; -DROP TRIGGER IF EXISTS after_delete_trees; - -# -validationchangelog -DROP TRIGGER IF EXISTS after_insert_validationchangelog; -DROP TRIGGER IF EXISTS after_update_validationchangelog; -DROP TRIGGER IF EXISTS after_delete_validationchangelog; \ No newline at end of file diff --git a/frontend/sqlscripting/migration-OoO/3-clearmaterializedviewtriggers.sql b/frontend/sqlscripting/migration-OoO/3-clearmaterializedviewtriggers.sql deleted file mode 100644 index d89b77a9..00000000 --- a/frontend/sqlscripting/migration-OoO/3-clearmaterializedviewtriggers.sql +++ /dev/null @@ -1,85 +0,0 @@ --- DEPRECATED. Skip this step - --- Drop triggers for coremeasurements -DROP TRIGGER IF EXISTS trg_coremeasurements_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_coremeasurements_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_coremeasurements_set_refresh_needed_after_delete; - --- Drop triggers for stems -DROP TRIGGER IF EXISTS trg_stems_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_stems_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_stems_set_refresh_needed_after_delete; - --- Drop triggers for trees -DROP TRIGGER IF EXISTS trg_trees_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_trees_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_trees_set_refresh_needed_after_delete; - --- Drop triggers for species -DROP TRIGGER IF EXISTS trg_species_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_species_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_species_set_refresh_needed_after_delete; - --- Drop triggers for quadrats -DROP TRIGGER IF EXISTS trg_quadrats_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_quadrats_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_quadrats_set_refresh_needed_after_delete; - --- Drop triggers for census -DROP TRIGGER IF EXISTS trg_census_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_census_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_census_set_refresh_needed_after_delete; - --- Drop triggers for cmattributes -DROP TRIGGER IF EXISTS trg_cmattributes_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_cmattributes_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_cmattributes_set_refresh_needed_after_delete; - --- Drop triggers for plots -DROP TRIGGER IF EXISTS trg_plots_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_plots_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_plots_set_refresh_needed_after_delete; - --- Drop triggers for subquadrats -DROP TRIGGER IF EXISTS trg_subquadrats_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_subquadrats_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_subquadrats_set_refresh_needed_after_delete; - --- Drop triggers for roles -DROP TRIGGER IF EXISTS trg_roles_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_roles_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_roles_set_refresh_needed_after_delete; - --- Drop triggers for attributes -DROP TRIGGER IF EXISTS trg_attributes_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_attributes_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_attributes_set_refresh_needed_after_delete; - --- Drop triggers for genus -DROP TRIGGER IF EXISTS trg_genus_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_genus_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_genus_set_refresh_needed_after_delete; - --- Drop triggers for family -DROP TRIGGER IF EXISTS trg_family_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_family_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_family_set_refresh_needed_after_delete; - --- Drop triggers for specieslimits -DROP TRIGGER IF EXISTS trg_specieslimits_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_specieslimits_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_specieslimits_set_refresh_needed_after_delete; - --- Drop triggers for quadratpersonnel -DROP TRIGGER IF EXISTS trg_quadratpersonnel_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_quadratpersonnel_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_quadratpersonnel_set_refresh_needed_after_delete; - --- Drop triggers for personnel -DROP TRIGGER IF EXISTS trg_personnel_set_refresh_needed_after_insert; -DROP TRIGGER IF EXISTS trg_personnel_set_refresh_needed_after_update; -DROP TRIGGER IF EXISTS trg_personnel_set_refresh_needed_after_delete; - --- Drop triggers for batchprocessingflag -DROP TRIGGER IF EXISTS trg_batchprocessingflag_before_insert; -DROP TRIGGER IF EXISTS trg_batchprocessingflag_after_update; diff --git a/frontend/sqlscripting/migration-OoO/4-migrationstatements.sql b/frontend/sqlscripting/migration-OoO/4-migrationstatements.sql deleted file mode 100644 index cd790561..00000000 --- a/frontend/sqlscripting/migration-OoO/4-migrationstatements.sql +++ /dev/null @@ -1,295 +0,0 @@ -set -foreign_key_checks = 0; - --- stable_sinharaja: old ctfsweb schema --- forestgeo_scbi: new schema. --- make sure you replace this for each new schema you pull/push from/to. - --- Insert into plots with ON DUPLICATE KEY UPDATE -INSERT INTO plots (PlotID, PlotName, LocationName, CountryName, DimensionX, DimensionY, DimensionUnits, Area, AreaUnits, - GlobalX, GlobalY, GlobalZ, CoordinateUnits, PlotShape, PlotDescription) -SELECT s.PlotID, LEFT (s.PlotName, 65535), LEFT (s.LocationName, 65535), c.CountryName, s.QDimX, s.QDimY, IF(s.PUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), s.PUOM, 'm'), s.Area, 'm2', co.GX, co.GY, co.GZ, IF(s.GUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), s.GUOM, 'm'), s.ShapeOfSite, LEFT (s.DescriptionOfSite, 65535) -FROM stable_sinharaja.Site s - LEFT JOIN stable_sinharaja.Country c -ON s.CountryID = c.CountryID - LEFT JOIN stable_sinharaja.Coordinates co ON s.PlotID = co.PlotID -GROUP BY s.PlotID, s.PlotName, s.LocationName, c.CountryName, s.QDimX, s.QDimY, s.PUOM, s.Area, s.GUOM, co.GX, co.GY, - co.GZ, s.ShapeOfSite, s.DescriptionOfSite -ON DUPLICATE KEY -UPDATE PlotName = IF(VALUES (PlotName) != '', VALUES (PlotName), plots.PlotName), - LocationName = IF(VALUES (LocationName) != '', VALUES (LocationName), plots.LocationName), - CountryName = IF(VALUES (CountryName) != '', VALUES (CountryName), plots.CountryName), - DimensionX = -VALUES (DimensionX), DimensionY = -VALUES (DimensionY), DimensionUnits = -VALUES (DimensionUnits), Area = -VALUES (Area), AreaUnits = -VALUES (AreaUnits), GlobalX = -VALUES (GlobalX), GlobalY = -VALUES (GlobalY), GlobalZ = -VALUES (GlobalZ), CoordinateUnits = -VALUES (CoordinateUnits), PlotShape = -VALUES (PlotShape), PlotDescription = IF(VALUES (PlotDescription) != '', VALUES (PlotDescription), plots.PlotDescription); - --- Insert into reference with ON DUPLICATE KEY UPDATE and handling '0000-00-00' dates -INSERT INTO reference (ReferenceID, PublicationTitle, FullReference, DateOfPublication, Citation) -SELECT r.ReferenceID, - r.PublicationTitle, - r.FullReference, - IF(CAST(r.DateofPublication AS CHAR) = '0000-00-00', NULL, r.DateofPublication) AS DateOfPublication, - NULL -FROM stable_sinharaja.reference r ON DUPLICATE KEY -UPDATE PublicationTitle = IF(VALUES (PublicationTitle) != '', VALUES (PublicationTitle), - reference.PublicationTitle), - FullReference = IF(VALUES (FullReference) != '', VALUES (FullReference), - reference.FullReference), - reference.DateOfPublication = -VALUES (DateOfPublication); - --- Insert into family with ON DUPLICATE KEY UPDATE -INSERT INTO family (FamilyID, Family, ReferenceID) -SELECT f.FamilyID, f.Family, f.ReferenceID -FROM stable_sinharaja.family f ON DUPLICATE KEY -UPDATE Family = IF(VALUES (Family) != '', VALUES (Family), family.Family), - ReferenceID = -VALUES (ReferenceID); - --- Insert into genus with ON DUPLICATE KEY UPDATE -INSERT INTO genus (GenusID, FamilyID, Genus, ReferenceID, GenusAuthority) -SELECT g.GenusID, g.FamilyID, g.Genus, g.ReferenceID, g.Authority -FROM stable_sinharaja.genus g ON DUPLICATE KEY -UPDATE FamilyID = -VALUES (FamilyID), Genus = IF(VALUES (Genus) != '', VALUES (Genus), genus.Genus), ReferenceID = -VALUES (ReferenceID), GenusAuthority = IF(VALUES (GenusAuthority) != '', VALUES (GenusAuthority), genus.GenusAuthority); - --- Insert into species with ON DUPLICATE KEY UPDATE -INSERT INTO species (SpeciesID, GenusID, SpeciesCode, SpeciesName, SubspeciesName, IDLevel, SpeciesAuthority, - SubspeciesAuthority, FieldFamily, Description, ValidCode, ReferenceID) -SELECT sp.SpeciesID, - sp.GenusID, - sp.Mnemonic, - sp.SpeciesName, - MIN(subs.SubSpeciesName), - sp.IDLevel, - sp.Authority, - MIN(subs.Authority), - sp.FieldFamily, LEFT (sp.Description, 65535), NULL, sp.ReferenceID -FROM stable_sinharaja.species sp - LEFT JOIN stable_sinharaja.subspecies subs -ON sp.SpeciesID = subs.SpeciesID - LEFT JOIN stable_sinharaja.reference ref ON sp.ReferenceID = ref.ReferenceID -GROUP BY sp.SpeciesID, sp.GenusID, sp.Mnemonic, sp.IDLevel, sp.Authority, sp.FieldFamily, sp.Description, sp.ReferenceID -ON DUPLICATE KEY -UPDATE GenusID = -VALUES (GenusID), SpeciesCode = -VALUES (SpeciesCode), SpeciesName = -VALUES (SpeciesName), SubspeciesName = IF(VALUES (SubspeciesName) != '', VALUES (SubspeciesName), species.SubspeciesName), IDLevel = -VALUES (IDLevel), SpeciesAuthority = IF(VALUES (SpeciesAuthority) != '', VALUES (SpeciesAuthority), species.SpeciesAuthority), SubspeciesAuthority = IF(VALUES (SubspeciesAuthority) != '', VALUES (SubspeciesAuthority), species.SubspeciesAuthority), FieldFamily = -VALUES (FieldFamily), Description = IF(VALUES (Description) != '', VALUES (Description), species.Description), ValidCode = -VALUES (ValidCode), ReferenceID = -VALUES (ReferenceID); - -UPDATE stable_sinharaja.census -SET StartDate = NULL -WHERE CAST(StartDate AS CHAR(10)) = '0000-00-00'; - --- Insert into census with ON DUPLICATE KEY UPDATE -INSERT INTO census (CensusID, PlotID, StartDate, EndDate, Description, PlotCensusNumber) -SELECT c.CensusID, - c.PlotID, - COALESCE(MIN(d.ExactDate), c.StartDate) AS StartDate, - COALESCE(MAX(d.ExactDate), c.EndDate) AS EndDate, LEFT (c.Description, 65535), c.PlotCensusNumber -FROM - stable_sinharaja.census c - LEFT JOIN - stable_sinharaja.dbh d -ON c.CensusID = d.CensusID -GROUP BY - c.CensusID -ON DUPLICATE KEY -UPDATE - PlotID = -VALUES (PlotID), StartDate = -VALUES (StartDate), EndDate = -VALUES (EndDate), Description = IF(VALUES (Description) != '', VALUES (Description), census.Description), PlotCensusNumber = -VALUES (PlotCensusNumber); - --- Insert into roles table -INSERT INTO roles (RoleID, RoleName, RoleDescription) -SELECT RoleID, Description, NULL -FROM stable_sinharaja.rolereference ON DUPLICATE KEY -UPDATE RoleName = -VALUES (RoleName), RoleDescription = -VALUES (RoleDescription); - --- Insert into personnel, ensuring each personnel is re-added for each CensusID with new PersonnelID --- Step 1: Create a temporary table to hold the intermediate results -CREATE -TEMPORARY TABLE tmp_personnel -SELECT c.CensusID, - p.FirstName, - p.LastName, - pr.RoleID -FROM stable_sinharaja.personnel p - CROSS JOIN - stable_sinharaja.census c - JOIN - stable_sinharaja.personnelrole pr ON p.PersonnelID = pr.PersonnelID; - --- Step 2: Insert into personnel from the temporary table, handling duplicates -INSERT INTO personnel (CensusID, FirstName, LastName, RoleID) -SELECT CensusID, - FirstName, - LastName, - RoleID -FROM tmp_personnel ON DUPLICATE KEY -UPDATE - RoleID = -VALUES (RoleID); - --- Step 3: Drop the temporary table -DROP -TEMPORARY TABLE tmp_personnel; - --- Insert into quadrats with ON DUPLICATE KEY UPDATE -INSERT INTO quadrats (QuadratID, PlotID, CensusID, QuadratName, StartX, StartY, DimensionX, DimensionY, DimensionUnits, - Area, AreaUnits, QuadratShape, CoordinateUnits) -SELECT q.QuadratID, - q.PlotID, - cq.CensusID, LEFT (q.QuadratName, 65535), MIN (co.PX), MIN (co.PY), s.QDimX, s.QDimY, IF(s.QUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), s.QUOM, 'm'), q.Area, IF(s.QUOM IN ('km2', 'hm2', 'dam2', 'm2', 'dm2', 'cm2', 'mm2'), s.QUOM, 'm2'), IF(q.IsStandardShape = 'Y', 'standard', 'not standard'), IF(s.GUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), s.GUOM, 'm') -FROM stable_sinharaja.quadrat q - LEFT JOIN stable_sinharaja.censusquadrat cq -ON q.QuadratID = cq.QuadratID - LEFT JOIN stable_sinharaja.Coordinates co ON q.QuadratID = co.QuadratID - LEFT JOIN stable_sinharaja.Site s ON q.PlotID = s.PlotID -GROUP BY q.QuadratID, q.PlotID, cq.CensusID, q.QuadratName, s.QDimX, s.QDimY, s.QUOM, q.Area, q.IsStandardShape, s.GUOM -ON DUPLICATE KEY -UPDATE PlotID = -VALUES (PlotID), CensusID = -VALUES (CensusID), QuadratName = IF(VALUES (QuadratName) != '', VALUES (QuadratName), quadrats.QuadratName), StartX = -VALUES (StartX), StartY = -VALUES (StartY), DimensionX = -VALUES (DimensionX), DimensionY = -VALUES (DimensionY), DimensionUnits = -VALUES (DimensionUnits), Area = -VALUES (Area), AreaUnits = -VALUES (AreaUnits), QuadratShape = -VALUES (QuadratShape), CoordinateUnits = -VALUES (CoordinateUnits); - --- Insert into trees with ON DUPLICATE KEY UPDATE -INSERT INTO trees (TreeID, TreeTag, SpeciesID) -SELECT t.TreeID, t.Tag, t.SpeciesID -FROM stable_sinharaja.tree t ON DUPLICATE KEY -UPDATE TreeTag = IF(VALUES (TreeTag) != '', VALUES (TreeTag), trees.TreeTag), - SpeciesID = -VALUES (SpeciesID); - --- Insert into stems with ON DUPLICATE KEY UPDATE -INSERT INTO stems (StemID, TreeID, QuadratID, StemNumber, StemTag, LocalX, LocalY, CoordinateUnits, Moved, - StemDescription) -SELECT s.StemID, - s.TreeID, - s.QuadratID, - s.StemNumber, - s.StemTag, - MIN(s.QX), - MIN(s.QY), - IF(si.QUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), si.QUOM, 'm') AS CoordinateUnits, - IF(s.Moved = 'Y', 1, 0) AS Moved, LEFT (s.StemDescription, 65535) -FROM stable_sinharaja.stem s - LEFT JOIN stable_sinharaja.quadrat q -ON q.QuadratID = s.QuadratID - LEFT JOIN stable_sinharaja.Site si ON q.PlotID = si.PlotID -GROUP BY s.StemID, s.TreeID, s.QuadratID, s.StemNumber, s.StemTag, s.Moved, s.StemDescription, si.QUOM -ON DUPLICATE KEY -UPDATE TreeID = -VALUES (TreeID), QuadratID = -VALUES (QuadratID), StemNumber = -VALUES (StemNumber), StemTag = IF(VALUES (StemTag) != '', VALUES (StemTag), stems.StemTag), LocalX = -VALUES (LocalX), LocalY = -VALUES (LocalY), CoordinateUnits = -VALUES (CoordinateUnits), Moved = -VALUES (Moved), StemDescription = IF(VALUES (StemDescription) != '', VALUES (StemDescription), stems.StemDescription); - --- Insert into coremeasurements with ON DUPLICATE KEY UPDATE -INSERT INTO coremeasurements (CoreMeasurementID, CensusID, StemID, IsValidated, MeasurementDate, MeasuredDBH, DBHUnit, - MeasuredHOM, HOMUnit, Description, UserDefinedFields) -SELECT dbh.DBHID, - dbh.CensusID, - dbh.StemID, - NULL, - dbh.ExactDate, - CAST(dbh.DBH AS DECIMAL(10, 6)), - 'cm', - CAST(dbh.HOM AS DECIMAL(10, 6)), - 'm', LEFT (dbh.Comments, 65535), NULL -FROM stable_sinharaja.dbh dbh -ON DUPLICATE KEY -UPDATE StemID = -VALUES (StemID), IsValidated = -VALUES (IsValidated), MeasurementDate = -VALUES (MeasurementDate), MeasuredDBH = -VALUES (MeasuredDBH), DBHUnit = -VALUES (DBHUnit), MeasuredHOM = -VALUES (MeasuredHOM), HOMUnit = -VALUES (HOMUnit), Description = IF(VALUES (Description) != '', VALUES (Description), coremeasurements.Description), UserDefinedFields = -VALUES (UserDefinedFields); - --- Insert into quadratpersonnel with ON DUPLICATE KEY UPDATE -INSERT INTO quadratpersonnel (QuadratPersonnelID, QuadratID, PersonnelID, CensusID) -SELECT dc.DataCollectionID, dc.QuadratID, pr.PersonnelID, dc.CensusID -FROM stable_sinharaja.datacollection dc - JOIN stable_sinharaja.personnelrole pr ON dc.PersonnelRoleID = pr.PersonnelRoleID ON DUPLICATE KEY -UPDATE QuadratID = -VALUES (QuadratID), PersonnelID = -VALUES (PersonnelID), CensusID = -VALUES (CensusID); - --- Insert into attributes with ON DUPLICATE KEY UPDATE -INSERT INTO attributes (Code, Description, Status) -SELECT ta.TSMCode, LEFT (ta.Description, 65535), IF(ta.Status IN ('alive', 'alive-not measured', 'dead', 'stem dead', 'broken below', 'omitted', 'missing'), ta.Status, NULL) -FROM stable_sinharaja.tsmattributes ta -GROUP BY ta.TSMCode, ta.Description, ta.Status -ON DUPLICATE KEY -UPDATE Description = IF(VALUES (Description) != '', VALUES (Description), attributes.Description), - Status = -VALUES (Status); - --- Insert into cmattributes with ON DUPLICATE KEY UPDATE -INSERT INTO cmattributes (CMAID, CoreMeasurementID, Code) -SELECT dbha.DBHAttID, dbha.DBHID, ta.TSMCode -FROM stable_sinharaja.dbhattributes dbha - JOIN stable_sinharaja.tsmattributes ta ON dbha.TSMID = ta.TSMID ON DUPLICATE KEY -UPDATE CoreMeasurementID = -VALUES (CoreMeasurementID), Code = -VALUES (Code); - --- Insert into specimens with ON DUPLICATE KEY UPDATE -INSERT INTO specimens (SpecimenID, StemID, PersonnelID, SpecimenNumber, SpeciesID, Herbarium, Voucher, CollectionDate, - DeterminedBy, Description) -SELECT sp.SpecimenID, - st.StemID, - pr.PersonnelID, - sp.SpecimenNumber, - sp.SpeciesID, - sp.Herbarium, - sp.Voucher, - sp.CollectionDate, - sp.DeterminedBy, LEFT (sp.Description, 65535) -FROM stable_sinharaja.specimen sp - LEFT JOIN stable_sinharaja.stem st -ON st.TreeID = sp.TreeID - LEFT JOIN stable_sinharaja.personnel pr ON sp.Collector = CONCAT(pr.FirstName, ' ', pr.LastName) - ON DUPLICATE KEY -UPDATE StemID = -VALUES (StemID), PersonnelID = -VALUES (PersonnelID), SpecimenNumber = -VALUES (SpecimenNumber), SpeciesID = -VALUES (SpeciesID), Herbarium = -VALUES (Herbarium), Voucher = -VALUES (Voucher), CollectionDate = -VALUES (CollectionDate), DeterminedBy = IF(VALUES (DeterminedBy) != '', VALUES (DeterminedBy), specimens.DeterminedBy), Description = IF(VALUES (Description) != '', VALUES (Description), specimens.Description); - -set -foreign_key_checks = 1; \ No newline at end of file diff --git a/frontend/sqlscripting/migration-OoO/5-recreatetriggers.sql b/frontend/sqlscripting/migration-OoO/5-recreatetriggers.sql deleted file mode 100644 index db8ef72b..00000000 --- a/frontend/sqlscripting/migration-OoO/5-recreatetriggers.sql +++ /dev/null @@ -1,1442 +0,0 @@ -DELIMITER -// - -CREATE TRIGGER after_insert_attributes - AFTER INSERT - ON attributes - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT('Code', NEW.Code, 'Description', NEW.Description, 'Status', NEW.Status); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('attributes', NEW.Code, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_attributes - AFTER UPDATE - ON attributes - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT('Code', OLD.Code, 'Description', OLD.Description, 'Status', OLD.Status); - SET new_json = JSON_OBJECT('Code', NEW.Code, 'Description', NEW.Description, 'Status', NEW.Status); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('attributes', NEW.Code, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_attributes - AFTER DELETE - ON attributes - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT('Code', OLD.Code, 'Description', OLD.Description, 'Status', OLD.Status); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('attributes', OLD.Code, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_insert_plots - AFTER INSERT - ON plots - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'PlotID', NEW.PlotID, - 'PlotName', NEW.PlotName, - 'LocationName', NEW.LocationName, - 'CountryName', NEW.CountryName, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'Area', NEW.Area, - 'AreaUnits', NEW.AreaUnits, - 'GlobalX', NEW.GlobalX, - 'GlobalY', NEW.GlobalY, - 'GlobalZ', NEW.GlobalZ, - 'CoordinateUnits', NEW.CoordinateUnits, - 'PlotShape', NEW.PlotShape, - 'PlotDescription', NEW.PlotDescription - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('plots', NEW.PlotID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_plots - AFTER UPDATE - ON plots - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'PlotID', OLD.PlotID, - 'PlotName', OLD.PlotName, - 'LocationName', OLD.LocationName, - 'CountryName', OLD.CountryName, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'Area', OLD.Area, - 'AreaUnits', OLD.AreaUnits, - 'GlobalX', OLD.GlobalX, - 'GlobalY', OLD.GlobalY, - 'GlobalZ', OLD.GlobalZ, - 'CoordinateUnits', OLD.CoordinateUnits, - 'PlotShape', OLD.PlotShape, - 'PlotDescription', OLD.PlotDescription - ); - SET new_json = JSON_OBJECT( - 'PlotID', NEW.PlotID, - 'PlotName', NEW.PlotName, - 'LocationName', NEW.LocationName, - 'CountryName', NEW.CountryName, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'Area', NEW.Area, - 'AreaUnits', NEW.AreaUnits, - 'GlobalX', NEW.GlobalX, - 'GlobalY', NEW.GlobalY, - 'GlobalZ', NEW.GlobalZ, - 'CoordinateUnits', NEW.CoordinateUnits, - 'PlotShape', NEW.PlotShape, - 'PlotDescription', NEW.PlotDescription - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('plots', NEW.PlotID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_plots - AFTER DELETE - ON plots - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'PlotID', OLD.PlotID, - 'PlotName', OLD.PlotName, - 'LocationName', OLD.LocationName, - 'CountryName', OLD.CountryName, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'Area', OLD.Area, - 'AreaUnits', OLD.AreaUnits, - 'GlobalX', OLD.GlobalX, - 'GlobalY', OLD.GlobalY, - 'GlobalZ', OLD.GlobalZ, - 'CoordinateUnits', OLD.CoordinateUnits, - 'PlotShape', OLD.PlotShape, - 'PlotDescription', OLD.PlotDescription - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('plots', OLD.PlotID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_insert_census - AFTER INSERT - ON census - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'CensusID', NEW.CensusID, - 'PlotID', NEW.PlotID, - 'StartDate', NEW.StartDate, - 'EndDate', NEW.EndDate, - 'Description', NEW.Description, - 'PlotCensusNumber', NEW.PlotCensusNumber - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('census', NEW.CensusID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_census - AFTER UPDATE - ON census - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'CensusID', OLD.CensusID, - 'PlotID', OLD.PlotID, - 'StartDate', OLD.StartDate, - 'EndDate', OLD.EndDate, - 'Description', OLD.Description, - 'PlotCensusNumber', OLD.PlotCensusNumber - ); - SET new_json = JSON_OBJECT( - 'CensusID', NEW.CensusID, - 'PlotID', NEW.PlotID, - 'StartDate', NEW.StartDate, - 'EndDate', NEW.EndDate, - 'Description', NEW.Description, - 'PlotCensusNumber', NEW.PlotCensusNumber - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('census', NEW.CensusID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_census - AFTER DELETE - ON census - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'CensusID', OLD.CensusID, - 'PlotID', OLD.PlotID, - 'StartDate', OLD.StartDate, - 'EndDate', OLD.EndDate, - 'Description', OLD.Description, - 'PlotCensusNumber', OLD.PlotCensusNumber - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('census', OLD.CensusID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - -DELIMITER -// - -CREATE TRIGGER after_insert_quadrats - AFTER INSERT - ON quadrats - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'QuadratID', NEW.QuadratID, - 'PlotID', NEW.PlotID, - 'CensusID', NEW.CensusID, - 'QuadratName', NEW.QuadratName, - 'StartX', NEW.StartX, - 'StartY', NEW.StartY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'Area', NEW.Area, - 'AreaUnits', NEW.AreaUnits, - 'QuadratShape', NEW.QuadratShape - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadrats', NEW.QuadratID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_quadrats - AFTER UPDATE - ON quadrats - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'QuadratID', OLD.QuadratID, - 'PlotID', OLD.PlotID, - 'CensusID', OLD.CensusID, - 'QuadratName', OLD.QuadratName, - 'StartX', OLD.StartX, - 'StartY', OLD.StartY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'Area', OLD.Area, - 'AreaUnits', OLD.AreaUnits, - 'QuadratShape', OLD.QuadratShape - ); - SET new_json = JSON_OBJECT( - 'QuadratID', NEW.QuadratID, - 'PlotID', NEW.PlotID, - 'CensusID', NEW.CensusID, - 'QuadratName', NEW.QuadratName, - 'StartX', NEW.StartX, - 'StartY', NEW.StartY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'Area', NEW.Area, - 'AreaUnits', NEW.AreaUnits, - 'QuadratShape', NEW.QuadratShape - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadrats', NEW.QuadratID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_quadrats - AFTER DELETE - ON quadrats - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'QuadratID', OLD.QuadratID, - 'PlotID', OLD.PlotID, - 'CensusID', OLD.CensusID, - 'QuadratName', OLD.QuadratName, - 'StartX', OLD.StartX, - 'StartY', OLD.StartY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'Area', OLD.Area, - 'AreaUnits', OLD.AreaUnits, - 'QuadratShape', OLD.QuadratShape - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadrats', OLD.QuadratID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - -DELIMITER -// - -CREATE TRIGGER after_insert_reference - AFTER INSERT - ON reference - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'ReferenceID', NEW.ReferenceID, - 'PublicationTitle', NEW.PublicationTitle, - 'FullReference', NEW.FullReference, - 'DateOfPublication', NEW.DateOfPublication, - 'Citation', NEW.Citation - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('reference', NEW.ReferenceID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_reference - AFTER UPDATE - ON reference - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'ReferenceID', OLD.ReferenceID, - 'PublicationTitle', OLD.PublicationTitle, - 'FullReference', OLD.FullReference, - 'DateOfPublication', OLD.DateOfPublication, - 'Citation', OLD.Citation - ); - SET new_json = JSON_OBJECT( - 'ReferenceID', NEW.ReferenceID, - 'PublicationTitle', NEW.PublicationTitle, - 'FullReference', NEW.FullReference, - 'DateOfPublication', NEW.DateOfPublication, - 'Citation', NEW.Citation - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('reference', NEW.ReferenceID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_reference - AFTER DELETE - ON reference - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'ReferenceID', OLD.ReferenceID, - 'PublicationTitle', OLD.PublicationTitle, - 'FullReference', OLD.FullReference, - 'DateOfPublication', OLD.DateOfPublication, - 'Citation', OLD.Citation - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('reference', OLD.ReferenceID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - -DELIMITER -// - -CREATE TRIGGER after_insert_family - AFTER INSERT - ON family - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'FamilyID', NEW.FamilyID, - 'Family', NEW.Family, - 'ReferenceID', NEW.ReferenceID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('family', NEW.FamilyID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_family - AFTER UPDATE - ON family - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'FamilyID', OLD.FamilyID, - 'Family', OLD.Family, - 'ReferenceID', OLD.ReferenceID - ); - SET new_json = JSON_OBJECT( - 'FamilyID', NEW.FamilyID, - 'Family', NEW.Family, - 'ReferenceID', NEW.ReferenceID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('family', NEW.FamilyID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_family - AFTER DELETE - ON family - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'FamilyID', OLD.FamilyID, - 'Family', OLD.Family, - 'ReferenceID', OLD.ReferenceID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('family', OLD.FamilyID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - -DELIMITER -// - -CREATE TRIGGER after_insert_genus - AFTER INSERT - ON genus - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'GenusID', NEW.GenusID, - 'FamilyID', NEW.FamilyID, - 'Genus', NEW.Genus, - 'ReferenceID', NEW.ReferenceID, - 'GenusAuthority', NEW.GenusAuthority - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('genus', NEW.GenusID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_genus - AFTER UPDATE - ON genus - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'GenusID', OLD.GenusID, - 'FamilyID', OLD.FamilyID, - 'Genus', OLD.Genus, - 'ReferenceID', OLD.ReferenceID, - 'GenusAuthority', OLD.GenusAuthority - ); - SET new_json = JSON_OBJECT( - 'GenusID', NEW.GenusID, - 'FamilyID', NEW.FamilyID, - 'Genus', NEW.Genus, - 'ReferenceID', NEW.ReferenceID, - 'GenusAuthority', NEW.GenusAuthority - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('genus', NEW.GenusID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_genus - AFTER DELETE - ON genus - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'GenusID', OLD.GenusID, - 'FamilyID', OLD.FamilyID, - 'Genus', OLD.Genus, - 'ReferenceID', OLD.ReferenceID, - 'GenusAuthority', OLD.GenusAuthority - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('genus', OLD.GenusID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - -DELIMITER -// - -CREATE TRIGGER after_insert_roles - AFTER INSERT - ON roles - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'RoleID', NEW.RoleID, - 'RoleName', NEW.RoleName, - 'RoleDescription', NEW.RoleDescription - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('roles', NEW.RoleID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_roles - AFTER UPDATE - ON roles - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'RoleID', OLD.RoleID, - 'RoleName', OLD.RoleName, - 'RoleDescription', OLD.RoleDescription - ); - SET new_json = JSON_OBJECT( - 'RoleID', NEW.RoleID, - 'RoleName', NEW.RoleName, - 'RoleDescription', NEW.RoleDescription - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('roles', NEW.RoleID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_roles - AFTER DELETE - ON roles - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'RoleID', OLD.RoleID, - 'RoleName', OLD.RoleName, - 'RoleDescription', OLD.RoleDescription - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('roles', OLD.RoleID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - -DELIMITER -// - -CREATE TRIGGER after_insert_personnel - AFTER INSERT - ON personnel - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'PersonnelID', NEW.PersonnelID, - 'CensusID', NEW.CensusID, - 'FirstName', NEW.FirstName, - 'LastName', NEW.LastName, - 'RoleID', NEW.RoleID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('personnel', NEW.PersonnelID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_personnel - AFTER UPDATE - ON personnel - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'PersonnelID', OLD.PersonnelID, - 'CensusID', OLD.CensusID, - 'FirstName', OLD.FirstName, - 'LastName', OLD.LastName, - 'RoleID', OLD.RoleID - ); - SET new_json = JSON_OBJECT( - 'PersonnelID', NEW.PersonnelID, - 'CensusID', NEW.CensusID, - 'FirstName', NEW.FirstName, - 'LastName', NEW.LastName, - 'RoleID', NEW.RoleID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('personnel', NEW.PersonnelID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_personnel - AFTER DELETE - ON personnel - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'PersonnelID', OLD.PersonnelID, - 'CensusID', OLD.CensusID, - 'FirstName', OLD.FirstName, - 'LastName', OLD.LastName, - 'RoleID', OLD.RoleID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('personnel', OLD.PersonnelID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - -DELIMITER -// - -CREATE TRIGGER after_insert_quadratpersonnel - AFTER INSERT - ON quadratpersonnel - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'QuadratPersonnelID', NEW.QuadratPersonnelID, - 'QuadratID', NEW.QuadratID, - 'PersonnelID', NEW.PersonnelID, - 'CensusID', NEW.CensusID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadratpersonnel', NEW.QuadratPersonnelID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_quadratpersonnel - AFTER UPDATE - ON quadratpersonnel - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'QuadratPersonnelID', OLD.QuadratPersonnelID, - 'QuadratID', OLD.QuadratID, - 'PersonnelID', OLD.PersonnelID, - 'CensusID', OLD.CensusID - ); - SET new_json = JSON_OBJECT( - 'QuadratPersonnelID', NEW.QuadratPersonnelID, - 'QuadratID', NEW.QuadratID, - 'PersonnelID', NEW.PersonnelID, - 'CensusID', NEW.CensusID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadratpersonnel', NEW.QuadratPersonnelID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_quadratpersonnel - AFTER DELETE - ON quadratpersonnel - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'QuadratPersonnelID', OLD.QuadratPersonnelID, - 'QuadratID', OLD.QuadratID, - 'PersonnelID', OLD.PersonnelID, - 'CensusID', OLD.CensusID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadratpersonnel', OLD.QuadratPersonnelID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - -DELIMITER -// - -CREATE TRIGGER after_insert_species - AFTER INSERT - ON species - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'SpeciesID', NEW.SpeciesID, - 'GenusID', NEW.GenusID, - 'SpeciesCode', NEW.SpeciesCode, - 'SpeciesName', NEW.SpeciesName, - 'SubspeciesName', NEW.SubspeciesName, - 'IDLevel', NEW.IDLevel, - 'SpeciesAuthority', NEW.SpeciesAuthority, - 'SubspeciesAuthority', NEW.SubspeciesAuthority, - 'FieldFamily', NEW.FieldFamily, - 'Description', NEW.Description, - 'ValidCode', NEW.ValidCode, - 'ReferenceID', NEW.ReferenceID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('species', NEW.SpeciesID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_species - AFTER UPDATE - ON species - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'SpeciesID', OLD.SpeciesID, - 'GenusID', OLD.GenusID, - 'SpeciesCode', OLD.SpeciesCode, - 'SpeciesName', OLD.SpeciesName, - 'SubspeciesName', OLD.SubspeciesName, - 'IDLevel', OLD.IDLevel, - 'SpeciesAuthority', OLD.SpeciesAuthority, - 'SubspeciesAuthority', OLD.SubspeciesAuthority, - 'FieldFamily', OLD.FieldFamily, - 'Description', OLD.Description, - 'ValidCode', OLD.ValidCode, - 'ReferenceID', OLD.ReferenceID - ); - SET new_json = JSON_OBJECT( - 'SpeciesID', NEW.SpeciesID, - 'GenusID', NEW.GenusID, - 'SpeciesCode', NEW.SpeciesCode, - 'SpeciesName', NEW.SpeciesName, - 'SubspeciesName', NEW.SubspeciesName, - 'IDLevel', NEW.IDLevel, - 'SpeciesAuthority', NEW.SpeciesAuthority, - 'SubspeciesAuthority', NEW.SubspeciesAuthority, - 'FieldFamily', NEW.FieldFamily, - 'Description', NEW.Description, - 'ValidCode', NEW.ValidCode, - 'ReferenceID', NEW.ReferenceID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('species', NEW.SpeciesID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_species - AFTER DELETE - ON species - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'SpeciesID', OLD.SpeciesID, - 'GenusID', OLD.GenusID, - 'SpeciesCode', OLD.SpeciesCode, - 'SpeciesName', OLD.SpeciesName, - 'SubspeciesName', OLD.SubspeciesName, - 'IDLevel', OLD.IDLevel, - 'SpeciesAuthority', OLD.SpeciesAuthority, - 'SubspeciesAuthority', OLD.SubspeciesAuthority, - 'FieldFamily', OLD.FieldFamily, - 'Description', OLD.Description, - 'ValidCode', OLD.ValidCode, - 'ReferenceID', OLD.ReferenceID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('species', OLD.SpeciesID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - -DELIMITER -// - -CREATE TRIGGER after_insert_specieslimits - AFTER INSERT - ON specieslimits - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'SpeciesLimitID', NEW.SpeciesLimitID, - 'SpeciesCode', NEW.SpeciesCode, - 'LimitType', NEW.LimitType, - 'UpperBound', NEW.UpperBound, - 'LowerBound', NEW.LowerBound, - 'Unit', NEW.Unit - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('specieslimits', NEW.SpeciesLimitID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_specieslimits - AFTER UPDATE - ON specieslimits - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'SpeciesLimitID', OLD.SpeciesLimitID, - 'SpeciesCode', OLD.SpeciesCode, - 'LimitType', OLD.LimitType, - 'UpperBound', OLD.UpperBound, - 'LowerBound', OLD.LowerBound, - 'Unit', OLD.Unit - ); - SET new_json = JSON_OBJECT( - 'SpeciesLimitID', NEW.SpeciesLimitID, - 'SpeciesCode', NEW.SpeciesCode, - 'LimitType', NEW.LimitType, - 'UpperBound', NEW.UpperBound, - 'LowerBound', NEW.LowerBound, - 'Unit', NEW.Unit - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('specieslimits', NEW.SpeciesLimitID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_specieslimits - AFTER DELETE - ON specieslimits - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'SpeciesLimitID', OLD.SpeciesLimitID, - 'SpeciesCode', OLD.SpeciesCode, - 'LimitType', OLD.LimitType, - 'UpperBound', OLD.UpperBound, - 'LowerBound', OLD.LowerBound, - 'Unit', OLD.Unit - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('specieslimits', OLD.SpeciesLimitID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - -DELIMITER -// - -CREATE TRIGGER after_insert_subquadrats - AFTER INSERT - ON subquadrats - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'SubquadratID', NEW.SubquadratID, - 'SubquadratName', NEW.SubquadratName, - 'QuadratID', NEW.QuadratID, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'QX', NEW.QX, - 'QY', NEW.QY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'Ordering', NEW.Ordering - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('subquadrats', NEW.SubquadratID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_subquadrats - AFTER UPDATE - ON subquadrats - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'SubquadratID', OLD.SubquadratID, - 'SubquadratName', OLD.SubquadratName, - 'QuadratID', OLD.QuadratID, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'QX', OLD.QX, - 'QY', OLD.QY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'Ordering', OLD.Ordering - ); - SET new_json = JSON_OBJECT( - 'SubquadratID', NEW.SubquadratID, - 'SubquadratName', NEW.SubquadratName, - 'QuadratID', NEW.QuadratID, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'QX', NEW.QX, - 'QY', NEW.QY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'Ordering', NEW.Ordering - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('subquadrats', NEW.SubquadratID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_subquadrats - AFTER DELETE - ON subquadrats - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'SubquadratID', OLD.SubquadratID, - 'SubquadratName', OLD.SubquadratName, - 'QuadratID', OLD.QuadratID, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'QX', OLD.QX, - 'QY', OLD.QY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'Ordering', OLD.Ordering - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('subquadrats', OLD.SubquadratID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - -DELIMITER -// - -CREATE TRIGGER after_insert_trees - AFTER INSERT - ON trees - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'TreeID', NEW.TreeID, - 'TreeTag', NEW.TreeTag, - 'SpeciesID', NEW.SpeciesID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('trees', NEW.TreeID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_trees - AFTER UPDATE - ON trees - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'TreeID', OLD.TreeID, - 'TreeTag', OLD.TreeTag, - 'SpeciesID', OLD.SpeciesID - ); - SET new_json = JSON_OBJECT( - 'TreeID', NEW.TreeID, - 'TreeTag', NEW.TreeTag, - 'SpeciesID', NEW.SpeciesID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('trees', NEW.TreeID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_trees - AFTER DELETE - ON trees - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'TreeID', OLD.TreeID, - 'TreeTag', OLD.TreeTag, - 'SpeciesID', OLD.SpeciesID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('trees', OLD.TreeID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - -DELIMITER -// - -CREATE TRIGGER after_insert_stems - AFTER INSERT - ON stems - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'StemID', NEW.StemID, - 'TreeID', NEW.TreeID, - 'QuadratID', NEW.QuadratID, - 'StemNumber', NEW.StemNumber, - 'StemTag', NEW.StemTag, - 'LocalX', NEW.LocalX, - 'LocalY', NEW.LocalY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'Moved', NEW.Moved, - 'StemDescription', NEW.StemDescription - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('stems', NEW.StemID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_stems - AFTER UPDATE - ON stems - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'StemID', OLD.StemID, - 'TreeID', OLD.TreeID, - 'QuadratID', OLD.QuadratID, - 'StemNumber', OLD.StemNumber, - 'StemTag', OLD.StemTag, - 'LocalX', OLD.LocalX, - 'LocalY', OLD.LocalY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'Moved', OLD.Moved, - 'StemDescription', OLD.StemDescription - ); - SET new_json = JSON_OBJECT( - 'StemID', NEW.StemID, - 'TreeID', NEW.TreeID, - 'QuadratID', NEW.QuadratID, - 'StemNumber', NEW.StemNumber, - 'StemTag', NEW.StemTag, - 'LocalX', NEW.LocalX, - 'LocalY', NEW.LocalY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'Moved', NEW.Moved, - 'StemDescription', NEW.StemDescription - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('stems', NEW.StemID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_stems - AFTER DELETE - ON stems - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'StemID', OLD.StemID, - 'TreeID', OLD.TreeID, - 'QuadratID', OLD.QuadratID, - 'StemNumber', OLD.StemNumber, - 'StemTag', OLD.StemTag, - 'LocalX', OLD.LocalX, - 'LocalY', OLD.LocalY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'Moved', OLD.Moved, - 'StemDescription', OLD.StemDescription - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('stems', OLD.StemID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - -DELIMITER -// - -CREATE TRIGGER after_insert_coremeasurements - AFTER INSERT - ON coremeasurements - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'CensusID', NEW.CensusID, - 'StemID', NEW.StemID, - 'IsValidated', NEW.IsValidated, - 'MeasurementDate', NEW.MeasurementDate, - 'MeasuredDBH', NEW.MeasuredDBH, - 'DBHUnit', NEW.DBHUnit, - 'MeasuredHOM', NEW.MeasuredHOM, - 'HOMUnit', NEW.HOMUnit, - 'Description', NEW.Description, - 'UserDefinedFields', NEW.UserDefinedFields - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('coremeasurements', NEW.CoreMeasurementID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_coremeasurements - AFTER UPDATE - ON coremeasurements - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'CensusID', OLD.CensusID, - 'StemID', OLD.StemID, - 'IsValidated', OLD.IsValidated, - 'MeasurementDate', OLD.MeasurementDate, - 'MeasuredDBH', OLD.MeasuredDBH, - 'DBHUnit', OLD.DBHUnit, - 'MeasuredHOM', OLD.MeasuredHOM, - 'HOMUnit', OLD.HOMUnit, - 'Description', OLD.Description, - 'UserDefinedFields', OLD.UserDefinedFields - ); - SET new_json = JSON_OBJECT( - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'CensusID', NEW.CensusID, - 'StemID', NEW.StemID, - 'IsValidated', NEW.IsValidated, - 'MeasurementDate', NEW.MeasurementDate, - 'MeasuredDBH', NEW.MeasuredDBH, - 'DBHUnit', NEW.DBHUnit, - 'MeasuredHOM', NEW.MeasuredHOM, - 'HOMUnit', NEW.HOMUnit, - 'Description', NEW.Description, - 'UserDefinedFields', NEW.UserDefinedFields - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('coremeasurements', NEW.CoreMeasurementID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_coremeasurements - AFTER DELETE - ON coremeasurements - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'CensusID', OLD.CensusID, - 'StemID', OLD.StemID, - 'IsValidated', OLD.IsValidated, - 'MeasurementDate', OLD.MeasurementDate, - 'MeasuredDBH', OLD.MeasuredDBH, - 'DBHUnit', OLD.DBHUnit, - 'MeasuredHOM', OLD.MeasuredHOM, - 'HOMUnit', OLD.HOMUnit, - 'Description', OLD.Description, - 'UserDefinedFields', OLD.UserDefinedFields - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('coremeasurements', OLD.CoreMeasurementID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - -DELIMITER -// - -CREATE TRIGGER after_insert_cmattributes - AFTER INSERT - ON cmattributes - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'CMAID', NEW.CMAID, - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'Code', NEW.Code - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmattributes', NEW.CMAID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_cmattributes - AFTER UPDATE - ON cmattributes - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'CMAID', OLD.CMAID, - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'Code', OLD.Code - ); - SET new_json = JSON_OBJECT( - 'CMAID', NEW.CMAID, - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'Code', NEW.Code - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmattributes', NEW.CMAID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_cmattributes - AFTER DELETE - ON cmattributes - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'CMAID', OLD.CMAID, - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'Code', OLD.Code - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmattributes', OLD.CMAID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - -DELIMITER -// - -CREATE TRIGGER after_insert_cmverrors - AFTER INSERT - ON cmverrors - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'CMVErrorID', NEW.CMVErrorID, - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'ValidationErrorID', NEW.ValidationErrorID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmverrors', NEW.CMVErrorID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_cmverrors - AFTER UPDATE - ON cmverrors - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'CMVErrorID', OLD.CMVErrorID, - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'ValidationErrorID', OLD.ValidationErrorID - ); - SET new_json = JSON_OBJECT( - 'CMVErrorID', NEW.CMVErrorID, - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'ValidationErrorID', NEW.ValidationErrorID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmverrors', NEW.CMVErrorID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_cmverrors - AFTER DELETE - ON cmverrors - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'CMVErrorID', OLD.CMVErrorID, - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'ValidationErrorID', OLD.ValidationErrorID - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmverrors', OLD.CMVErrorID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - -DELIMITER -// - -CREATE TRIGGER after_insert_specimens - AFTER INSERT - ON specimens - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'SpecimenID', NEW.SpecimenID, - 'StemID', NEW.StemID, - 'PersonnelID', NEW.PersonnelID, - 'SpecimenNumber', NEW.SpecimenNumber, - 'SpeciesID', NEW.SpeciesID, - 'Herbarium', NEW.Herbarium, - 'Voucher', NEW.Voucher, - 'CollectionDate', NEW.CollectionDate, - 'DeterminedBy', NEW.DeterminedBy, - 'Description', NEW.Description - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('specimens', NEW.SpecimenID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_specimens - AFTER UPDATE - ON specimens - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'SpecimenID', OLD.SpecimenID, - 'StemID', OLD.StemID, - 'PersonnelID', OLD.PersonnelID, - 'SpecimenNumber', OLD.SpecimenNumber, - 'SpeciesID', OLD.SpeciesID, - 'Herbarium', OLD.Herbarium, - 'Voucher', OLD.Voucher, - 'CollectionDate', OLD.CollectionDate, - 'DeterminedBy', OLD.DeterminedBy, - 'Description', OLD.Description - ); - SET new_json = JSON_OBJECT( - 'SpecimenID', NEW.SpecimenID, - 'StemID', NEW.StemID, - 'PersonnelID', NEW.PersonnelID, - 'SpecimenNumber', NEW.SpecimenNumber, - 'SpeciesID', NEW.SpeciesID, - 'Herbarium', NEW.Herbarium, - 'Voucher', NEW.Voucher, - 'CollectionDate', NEW.CollectionDate, - 'DeterminedBy', NEW.DeterminedBy, - 'Description', NEW.Description - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('specimens', NEW.SpecimenID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_specimens - AFTER DELETE - ON specimens - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'SpecimenID', OLD.SpecimenID, - 'StemID', OLD.StemID, - 'PersonnelID', OLD.PersonnelID, - 'SpecimenNumber', OLD.SpecimenNumber, - 'SpeciesID', OLD.SpeciesID, - 'Herbarium', OLD.Herbarium, - 'Voucher', OLD.Voucher, - 'CollectionDate', OLD.CollectionDate, - 'DeterminedBy', OLD.DeterminedBy, - 'Description', OLD.Description - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('specimens', OLD.SpecimenID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - -DELIMITER -// - -CREATE TRIGGER after_insert_validationchangelog - AFTER INSERT - ON validationchangelog - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - SET new_json = JSON_OBJECT( - 'ValidationRunID', NEW.ValidationRunID, - 'ProcedureName', NEW.ProcedureName, - 'RunDateTime', NEW.RunDateTime, - 'TargetRowID', NEW.TargetRowID, - 'ValidationOutcome', NEW.ValidationOutcome, - 'ErrorMessage', NEW.ErrorMessage, - 'ValidationCriteria', NEW.ValidationCriteria, - 'MeasuredValue', NEW.MeasuredValue, - 'ExpectedValueRange', NEW.ExpectedValueRange, - 'AdditionalDetails', NEW.AdditionalDetails - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('validationchangelog', NEW.ValidationRunID, 'INSERT', new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_update_validationchangelog - AFTER UPDATE - ON validationchangelog - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - SET old_json = JSON_OBJECT( - 'ValidationRunID', OLD.ValidationRunID, - 'ProcedureName', OLD.ProcedureName, - 'RunDateTime', OLD.RunDateTime, - 'TargetRowID', OLD.TargetRowID, - 'ValidationOutcome', OLD.ValidationOutcome, - 'ErrorMessage', OLD.ErrorMessage, - 'ValidationCriteria', OLD.ValidationCriteria, - 'MeasuredValue', OLD.MeasuredValue, - 'ExpectedValueRange', OLD.ExpectedValueRange, - 'AdditionalDetails', OLD.AdditionalDetails - ); - SET new_json = JSON_OBJECT( - 'ValidationRunID', NEW.ValidationRunID, - 'ProcedureName', NEW.ProcedureName, - 'RunDateTime', NEW.RunDateTime, - 'TargetRowID', NEW.TargetRowID, - 'ValidationOutcome', NEW.ValidationOutcome, - 'ErrorMessage', NEW.ErrorMessage, - 'ValidationCriteria', NEW.ValidationCriteria, - 'MeasuredValue', NEW.MeasuredValue, - 'ExpectedValueRange', NEW.ExpectedValueRange, - 'AdditionalDetails', NEW.AdditionalDetails - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('validationchangelog', NEW.ValidationRunID, 'UPDATE', old_json, new_json, NOW(), 'User'); -END // - -CREATE TRIGGER after_delete_validationchangelog - AFTER DELETE - ON validationchangelog - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - SET old_json = JSON_OBJECT( - 'ValidationRunID', OLD.ValidationRunID, - 'ProcedureName', OLD.ProcedureName, - 'RunDateTime', OLD.RunDateTime, - 'TargetRowID', OLD.TargetRowID, - 'ValidationOutcome', OLD.ValidationOutcome, - 'ErrorMessage', OLD.ErrorMessage, - 'ValidationCriteria', OLD.ValidationCriteria, - 'MeasuredValue', OLD.MeasuredValue, - 'ExpectedValueRange', OLD.ExpectedValueRange, - 'AdditionalDetails', OLD.AdditionalDetails - ); - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('validationchangelog', OLD.ValidationRunID, 'DELETE', old_json, NOW(), 'User'); -END // - -DELIMITER; - - diff --git a/frontend/sqlscripting/migration-OoO/6-recreateviews.sql b/frontend/sqlscripting/migration-OoO/6-recreateviews.sql deleted file mode 100644 index 711699d0..00000000 --- a/frontend/sqlscripting/migration-OoO/6-recreateviews.sql +++ /dev/null @@ -1,186 +0,0 @@ -CREATE VIEW alltaxonomiesview AS -SELECT s.SpeciesID AS SpeciesID, - f.FamilyID AS FamilyID, - g.GenusID AS GenusID, - r.ReferenceID AS ReferenceID, - s.SpeciesCode AS SpeciesCode, - f.Family AS Family, - g.Genus AS Genus, - g.GenusAuthority AS GenusAuthority, - s.SpeciesName AS SpeciesName, - s.SubspeciesName AS SubSpeciesName, - s.IDLevel AS SpeciesIDLevel, - s.SpeciesAuthority AS SpeciesAuthority, - s.SubspeciesAuthority AS SubspeciesAuthority, - s.ValidCode AS ValidCode, - s.FieldFamily AS FieldFamily, - s.Description AS SpeciesDescription, - r.PublicationTitle AS PublicationTitle, - r.FullReference AS FullReference, - r.DateOfPublication AS DateOfPublication, - r.Citation AS Citation -FROM family f - JOIN genus g ON f.FamilyID = g.FamilyID - JOIN species s ON g.GenusID = s.GenusID - LEFT JOIN reference r ON s.ReferenceID = r.ReferenceID; - - -CREATE VIEW measurementssummaryview AS -SELECT cm.CoreMeasurementID AS CoreMeasurementID, - p.PlotID AS PlotID, - cm.CensusID AS CensusID, - q.QuadratID AS QuadratID, - s.SpeciesID AS SpeciesID, - t.TreeID AS TreeID, - st.StemID AS StemID, - qp.PersonnelID AS PersonnelID, - p.PlotName AS PlotName, - q.QuadratName AS QuadratName, - s.SpeciesCode AS SpeciesCode, - t.TreeTag AS TreeTag, - st.StemTag AS StemTag, - st.LocalX AS StemLocalX, - st.LocalY AS StemLocalY, - st.CoordinateUnits AS StemUnits, - COALESCE(CONCAT(pe.FirstName, ' ', pe.LastName), 'Unknown') AS PersonnelName, - cm.MeasurementDate AS MeasurementDate, - cm.MeasuredDBH AS MeasuredDBH, - cm.DBHUnit AS DBHUnits, - cm.MeasuredHOM AS MeasuredHOM, - cm.HOMUnit AS HOMUnits, - cm.IsValidated AS IsValidated, - cm.Description AS Description, - (SELECT GROUP_CONCAT(ca.Code SEPARATOR '; ') - FROM cmattributes ca - WHERE ca.CoreMeasurementID = cm.CoreMeasurementID) AS Attributes -FROM coremeasurements cm - LEFT JOIN stems st ON cm.StemID = st.StemID - LEFT JOIN trees t ON st.TreeID = t.TreeID - LEFT JOIN species s ON t.SpeciesID = s.SpeciesID - LEFT JOIN genus g ON s.GenusID = g.GenusID - LEFT JOIN family f ON g.FamilyID = f.FamilyID - LEFT JOIN quadrats q ON st.QuadratID = q.QuadratID - LEFT JOIN plots p ON q.PlotID = p.PlotID - LEFT JOIN census c ON cm.CensusID = c.CensusID - LEFT JOIN quadratpersonnel qp ON q.QuadratID = qp.QuadratID - LEFT JOIN personnel pe ON qp.PersonnelID = pe.PersonnelID -GROUP BY cm.CoreMeasurementID, p.PlotID, cm.CensusID, q.QuadratID, s.SpeciesID, t.TreeID, st.StemID, qp.PersonnelID, - p.PlotName, q.QuadratName, s.SpeciesCode, t.TreeTag, st.StemTag, st.LocalX, st.LocalY, st.CoordinateUnits, - pe.FirstName, pe.LastName, cm.MeasurementDate, cm.MeasuredDBH, cm.DBHUnit, cm.MeasuredHOM, cm.HOMUnit, - cm.IsValidated, cm.Description; - - -CREATE VIEW stemtaxonomiesview AS -SELECT s.StemID AS StemID, - t.TreeID AS TreeID, - q.QuadratID AS QuadratID, - c.CensusID AS CensusID, - p.PlotID AS PlotID, - f.FamilyID AS FamilyID, - g.GenusID AS GenusID, - sp.SpeciesID AS SpeciesID, - s.StemTag AS StemTag, - t.TreeTag AS TreeTag, - sp.SpeciesCode AS SpeciesCode, - f.Family AS Family, - g.Genus AS Genus, - sp.SpeciesName AS SpeciesName, - sp.SubspeciesName AS SubspeciesName, - sp.ValidCode AS ValidCode, - g.GenusAuthority AS GenusAuthority, - sp.SpeciesAuthority AS SpeciesAuthority, - sp.SubspeciesAuthority AS SubspeciesAuthority, - sp.IDLevel AS SpeciesIDLevel, - sp.FieldFamily AS SpeciesFieldFamily -FROM stems s - JOIN trees t ON s.TreeID = t.TreeID - JOIN quadrats q ON s.QuadratID = q.QuadratID - JOIN census c ON q.CensusID = c.CensusID - JOIN plots p ON c.PlotID = p.PlotID - JOIN species sp ON t.SpeciesID = sp.SpeciesID - JOIN genus g ON sp.GenusID = g.GenusID - LEFT JOIN family f ON g.FamilyID = f.FamilyID; - - -CREATE VIEW viewfulltableview AS -SELECT cm.CoreMeasurementID AS CoreMeasurementID, - cm.MeasurementDate AS MeasurementDate, - cm.MeasuredDBH AS MeasuredDBH, - cm.DBHUnit AS DBHUnits, - cm.MeasuredHOM AS MeasuredHOM, - cm.HOMUnit AS HOMUnits, - cm.Description AS Description, - cm.IsValidated AS IsValidated, - p.PlotID AS PlotID, - p.PlotName AS PlotName, - p.LocationName AS LocationName, - p.CountryName AS CountryName, - p.DimensionX AS DimensionX, - p.DimensionY AS DimensionY, - p.Area AS PlotArea, - p.GlobalX AS GlobalX, - p.GlobalY AS GlobalY, - p.GlobalZ AS GlobalZ, - p.DimensionUnits AS PlotUnit, - p.PlotShape AS PlotShape, - p.PlotDescription AS PlotDescription, - c.CensusID AS CensusID, - c.StartDate AS CensusStartDate, - c.EndDate AS CensusEndDate, - c.Description AS CensusDescription, - c.PlotCensusNumber AS PlotCensusNumber, - q.QuadratID AS QuadratID, - q.QuadratName AS QuadratName, - q.DimensionX AS QuadratDimensionX, - q.DimensionY AS QuadratDimensionY, - q.Area AS QuadratArea, - q.QuadratShape AS QuadratShape, - q.DimensionUnits AS QuadratUnit, - sq.SubquadratID AS SubquadratID, - sq.SubquadratName AS SubquadratName, - sq.DimensionX AS SubquadratDimensionX, - sq.DimensionY AS SubquadratDimensionY, - sq.QX AS QX, - sq.QY AS QY, - sq.CoordinateUnits AS SubquadratUnit, - t.TreeID AS TreeID, - t.TreeTag AS TreeTag, - s.StemID AS StemID, - s.StemTag AS StemTag, - s.LocalX AS StemLocalX, - s.LocalY AS StemLocalY, - s.CoordinateUnits AS StemUnits, - per.PersonnelID AS PersonnelID, - per.FirstName AS FirstName, - per.LastName AS LastName, - r.RoleName AS PersonnelRoles, - sp.SpeciesID AS SpeciesID, - sp.SpeciesCode AS SpeciesCode, - sp.SpeciesName AS SpeciesName, - sp.SubspeciesName AS SubspeciesName, - sp.SubspeciesAuthority AS SubspeciesAuthority, - sp.IDLevel AS SpeciesIDLevel, - g.GenusID AS GenusID, - g.Genus AS Genus, - g.GenusAuthority AS GenusAuthority, - fam.FamilyID AS FamilyID, - fam.Family AS Family, - attr.Code AS AttributeCode, - attr.Description AS AttributeDescription, - attr.Status AS AttributeStatus -FROM coremeasurements cm - LEFT JOIN stems s ON cm.StemID = s.StemID - LEFT JOIN trees t ON s.TreeID = t.TreeID - LEFT JOIN species sp ON t.SpeciesID = sp.SpeciesID - LEFT JOIN genus g ON sp.GenusID = g.GenusID - LEFT JOIN family fam ON g.FamilyID = fam.FamilyID - LEFT JOIN specieslimits sl ON sp.SpeciesCode = sl.SpeciesCode - LEFT JOIN quadrats q ON s.QuadratID = q.QuadratID - LEFT JOIN quadratpersonnel qp ON q.QuadratID = qp.QuadratID - LEFT JOIN personnel per ON qp.PersonnelID = per.PersonnelID - LEFT JOIN plots p ON q.PlotID = p.PlotID - LEFT JOIN subquadrats sq ON q.QuadratID = sq.QuadratID - LEFT JOIN census c ON cm.CensusID = c.CensusID - LEFT JOIN roles r ON per.RoleID = r.RoleID - LEFT JOIN attributes attr ON cm.CoreMeasurementID = attr.Code - LEFT JOIN cmattributes cma ON cm.CoreMeasurementID = cma.CoreMeasurementID AND attr.Code = cma.Code; \ No newline at end of file diff --git a/frontend/sqlscripting/migration-OoO/7-recreateprocedures.sql b/frontend/sqlscripting/migration-OoO/7-recreateprocedures.sql deleted file mode 100644 index c8110cd6..00000000 --- a/frontend/sqlscripting/migration-OoO/7-recreateprocedures.sql +++ /dev/null @@ -1,2159 +0,0 @@ -create -definer = azureroot@`%` procedure RefreshMeasurementsSummary() -BEGIN -TRUNCATE TABLE measurementssummary; -INSERT INTO measurementssummary -SELECT cm.CoreMeasurementID AS CoreMeasurementID, - st.StemID AS StemID, - t.TreeID AS TreeID, - s.SpeciesID AS SpeciesID, - q.QuadratID AS QuadratID, - q.PlotID AS PlotID, - cm.CensusID AS CensusID, - s.SpeciesName AS SpeciesName, - s.SubspeciesName AS SubspeciesName, - s.SpeciesCode AS SpeciesCode, - t.TreeTag AS TreeTag, - st.StemTag AS StemTag, - st.LocalX AS StemLocalX, - st.LocalY AS StemLocalY, - st.CoordinateUnits AS StemUnits, - q.QuadratName AS QuadratName, - cm.MeasurementDate AS MeasurementDate, - cm.MeasuredDBH AS MeasuredDBH, - cm.DBHUnit AS DBHUnits, - cm.MeasuredHOM AS MeasuredHOM, - cm.HOMUnit AS HOMUnits, - cm.IsValidated AS IsValidated, - cm.Description AS Description, - (SELECT GROUP_CONCAT(ca.Code SEPARATOR '; ') - FROM cmattributes ca - WHERE ca.CoreMeasurementID = cm.CoreMeasurementID) AS Attributes -FROM coremeasurements cm - LEFT JOIN stems st ON cm.StemID = st.StemID - LEFT JOIN trees t ON st.TreeID = t.TreeID - LEFT JOIN species s ON t.SpeciesID = s.SpeciesID - LEFT JOIN quadrats q ON st.QuadratID = q.QuadratID - LEFT JOIN census c ON cm.CensusID = c.CensusID; -END; - -create -definer = azureroot@`%` procedure RefreshViewFullTable() -BEGIN - -- Truncate the materialized table -TRUNCATE TABLE viewfulltable; - --- Insert data from the view into the materialized table -INSERT INTO viewfulltable (CoreMeasurementID, - MeasurementDate, - MeasuredDBH, - DBHUnits, - MeasuredHOM, - HOMUnits, - Description, - IsValidated, - PlotID, - PlotName, - LocationName, - CountryName, - DimensionX, - DimensionY, - PlotDimensionUnits, - PlotArea, - PlotAreaUnits, - PlotGlobalX, - PlotGlobalY, - PlotGlobalZ, - PlotCoordinateUnits, - PlotShape, - PlotDescription, - CensusID, - CensusStartDate, - CensusEndDate, - CensusDescription, - PlotCensusNumber, - QuadratID, - QuadratName, - QuadratDimensionX, - QuadratDimensionY, - QuadratDimensionUnits, - QuadratArea, - QuadratAreaUnits, - QuadratStartX, - QuadratStartY, - QuadratCoordinateUnits, - QuadratShape, - SubquadratID, - SubquadratName, - SubquadratDimensionX, - SubquadratDimensionY, - SubquadratDimensionUnits, - SubquadratX, - SubquadratY, - SubquadratCoordinateUnits, - TreeID, - TreeTag, - StemID, - StemTag, - StemLocalX, - StemLocalY, - StemCoordinateUnits, - PersonnelID, - FirstName, - LastName, - PersonnelRoles, - SpeciesID, - SpeciesCode, - SpeciesName, - SubspeciesName, - SubspeciesAuthority, - SpeciesIDLevel, - GenusID, - Genus, - GenusAuthority, - FamilyID, - Family, - AttributeCode, - AttributeDescription, - AttributeStatus) -SELECT cm.CoreMeasurementID, - cm.MeasurementDate, - cm.MeasuredDBH, - cm.DBHUnit, - cm.MeasuredHOM, - cm.HOMUnit, - cm.Description, - cm.IsValidated, - p.PlotID, - p.PlotName, - p.LocationName, - p.CountryName, - p.DimensionX, - p.DimensionY, - p.DimensionUnits, - p.Area, - p.AreaUnits, - p.GlobalX, - p.GlobalY, - p.GlobalZ, - p.CoordinateUnits, - p.PlotShape, - p.PlotDescription, - c.CensusID, - c.StartDate, - c.EndDate, - c.Description, - c.PlotCensusNumber, - q.QuadratID, - q.QuadratName, - q.DimensionX, - q.DimensionY, - q.DimensionUnits, - q.Area, - q.AreaUnits, - q.StartX, - q.StartY, - q.CoordinateUnits, - q.QuadratShape, - sq.SubquadratID, - sq.SubquadratName, - sq.DimensionX, - sq.DimensionY, - sq.DimensionUnits, - sq.QX, - sq.QY, - sq.CoordinateUnits, - t.TreeID, - t.TreeTag, - s.StemID, - s.StemTag, - s.LocalX, - s.LocalY, - s.CoordinateUnits, - per.PersonnelID, - per.FirstName, - per.LastName, - r.RoleName, - sp.SpeciesID, - sp.SpeciesCode, - sp.SpeciesName, - sp.SubspeciesName, - sp.SubspeciesAuthority, - sp.IDLevel, - g.GenusID, - g.Genus, - g.GenusAuthority, - fam.FamilyID, - fam.Family, - attr.Code, - attr.Description, - attr.Status -FROM coremeasurements cm - LEFT JOIN stems s ON cm.StemID = s.StemID - LEFT JOIN trees t ON s.TreeID = t.TreeID - LEFT JOIN species sp ON t.SpeciesID = sp.SpeciesID - LEFT JOIN genus g ON sp.GenusID = g.GenusID - LEFT JOIN family fam ON g.FamilyID = fam.FamilyID - LEFT JOIN specieslimits sl ON sp.SpeciesCode = sl.SpeciesCode - LEFT JOIN quadrats q ON s.QuadratID = q.QuadratID - LEFT JOIN quadratpersonnel qp ON q.QuadratID = qp.QuadratID - LEFT JOIN personnel per ON qp.PersonnelID = per.PersonnelID - LEFT JOIN plots p ON q.PlotID = p.PlotID - LEFT JOIN subquadrats sq ON q.QuadratID = sq.QuadratID - LEFT JOIN census c ON cm.CensusID = c.CensusID - LEFT JOIN roles r ON per.RoleID = r.RoleID - LEFT JOIN cmattributes cma ON cm.CoreMeasurementID = cma.CoreMeasurementID - LEFT JOIN attributes attr ON cma.Code = attr.Code; -END; - -create -definer = azureroot@`%` procedure UpdateValidationStatus(IN p_PlotID int, IN p_CensusID int, OUT RowsValidated int) -BEGIN - -- Create a temporary table to store CoreMeasurementIDs - CREATE -TEMPORARY TABLE IF NOT EXISTS TempUpdatedIDs (CoreMeasurementID INT); - - -- Clear the temporary table -TRUNCATE TABLE TempUpdatedIDs; - --- Insert the CoreMeasurementIDs of the rows to be updated into the temporary table -INSERT INTO TempUpdatedIDs (CoreMeasurementID) -SELECT cm.CoreMeasurementID -FROM coremeasurements cm - LEFT JOIN cmverrors cme ON cm.CoreMeasurementID = cme.CoreMeasurementID - LEFT JOIN stems s on cm.StemID = s.StemID - LEFT JOIN quadrats q on s.QuadratID = q.QuadratID -WHERE cm.IsValidated = FALSE - AND (q.PlotID = p_PlotID OR p_PlotID IS NULL) - AND (q.CensusID = p_CensusID OR p_CensusID IS NULL) - AND cme.CoreMeasurementID IS NULL; - --- Update the IsValidated column -UPDATE coremeasurements cm - INNER JOIN TempUpdatedIDs tmp -ON cm.CoreMeasurementID = tmp.CoreMeasurementID - SET cm.IsValidated = TRUE; - --- Get the count of rows that have been updated -SET -RowsValidated = ROW_COUNT(); - - -- Select the CoreMeasurementIDs from the temporary table -SELECT CoreMeasurementID -FROM TempUpdatedIDs; - --- Optionally, drop the temporary table -DROP -TEMPORARY TABLE IF EXISTS TempUpdatedIDs; -END; - -create -definer = azureroot@`%` procedure ValidateDBHGrowthExceedsMax(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE -vCoreMeasurementID INT; - DECLARE -vPrevDBH DECIMAL(10, 2); - DECLARE -vCurrDBH DECIMAL(10, 2); - DECLARE -validationResult BIT; - DECLARE -errorMessage VARCHAR(255); - DECLARE -validationCriteria TEXT; - DECLARE -measuredValue VARCHAR(255); - DECLARE -expectedValueRange VARCHAR(255); - DECLARE -additionalDetails TEXT; - DECLARE -insertCount INT DEFAULT 0; - DECLARE -expectedCount INT; - DECLARE -successMessage VARCHAR(255); - DECLARE -done INT DEFAULT FALSE; - DECLARE -veID INT; - DECLARE -cur CURSOR FOR -SELECT cm2.CoreMeasurementID, cm1.MeasuredDBH, cm2.MeasuredDBH -FROM coremeasurements cm1 - JOIN coremeasurements cm2 - ON cm1.StemID = cm2.StemID - AND YEAR (cm2.MeasurementDate) = YEAR (cm1.MeasurementDate) + 1 - LEFT JOIN stems st2 -ON cm2.StemID = st2.StemID - LEFT JOIN quadrats q ON st2.QuadratID = q.QuadratID - LEFT JOIN cmattributes cma - ON cm1.CoreMeasurementID = cma.CoreMeasurementID - LEFT JOIN attributes a - ON cma.Code = a.Code -WHERE (a.Status NOT IN ('dead' - , 'stem dead' - , 'broken below' - , 'missing' - , 'omitted') - OR a.Status IS NULL) - AND cm1.MeasuredDBH IS NOT NULL - AND cm2.MeasuredDBH IS NOT NULL - AND (cm2.MeasuredDBH - cm1.MeasuredDBH - > 65) - AND cm1.IsValidated IS TRUE - AND cm2.IsValidated IS FALSE - AND (p_CensusID IS NULL - OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL - OR q.PlotID = p_PlotID); - -DECLARE -CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE -TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF -p_CensusID IS NULL THEN - SET p_CensusID = -1; -END IF; - IF -p_PlotID IS NULL THEN - SET p_PlotID = -1; -END IF; - -SELECT COUNT(*) -INTO expectedCount -FROM coremeasurements cm1 - JOIN coremeasurements cm2 - ON cm1.StemID = cm2.StemID - AND YEAR (cm2.MeasurementDate) = YEAR (cm1.MeasurementDate) + 1 - LEFT JOIN stems st2 -ON cm2.StemID = st2.StemID - LEFT JOIN quadrats q ON st2.QuadratID = q.QuadratID - LEFT JOIN cmattributes cma - ON cm1.CoreMeasurementID = cma.CoreMeasurementID - LEFT JOIN attributes a - ON cma.Code = a.Code -WHERE (a.Status NOT IN ('dead' - , 'stem dead' - , 'broken below' - , 'missing' - , 'omitted') - OR a.Status IS NULL) - AND cm1.MeasuredDBH IS NOT NULL - AND cm2.MeasuredDBH IS NOT NULL - AND (cm2.MeasuredDBH - cm1.MeasuredDBH - > 65) - AND cm1.IsValidated IS TRUE - AND cm2.IsValidated IS FALSE - AND (p_CensusID = -1 - OR q.CensusID = p_CensusID) - AND (p_PlotID = -1 - OR q.PlotID = p_PlotID); - --- Fetch the ValidationErrorID for this stored procedure -SELECT ValidationID -INTO veID -FROM catalog.validationprocedures -WHERE ProcedureName = 'ValidateDBHGrowthExceedsMax'; - -OPEN cur; -loop1 -: - LOOP - FETCH cur INTO vCoreMeasurementID, vPrevDBH, vCurrDBH; - IF -done THEN - LEAVE loop1; -END IF; - - SET -validationCriteria = 'Annual DBH Growth'; - SET -measuredValue = CONCAT('Previous DBH: ', vPrevDBH, ', Current DBH: ', vCurrDBH); - SET -expectedValueRange = 'Growth <= 65'; - SET -additionalDetails = 'Checked for excessive DBH growth over a year'; - - IF -vCurrDBH - vPrevDBH > 65 THEN - SET validationResult = 0; - SET -errorMessage = 'Growth exceeds max threshold.'; - IF -NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); -END IF; -INSERT INTO FailedValidations (CoreMeasurementID) -VALUES (vCoreMeasurementID); -SET -insertCount = insertCount + 1; -ELSE - SET validationResult = 1; - SET -errorMessage = NULL; -END IF; - -INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) -VALUES ('ValidateDBHGrowthExceedsMax', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); -END LOOP; -CLOSE cur; - -SET -successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); -SELECT expectedCount AS TotalRows, - insertCount AS FailedRows, - successMessage AS Message; - -SELECT CoreMeasurementID -FROM FailedValidations; - -DROP -TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create -definer = azureroot@`%` procedure ValidateDBHShrinkageExceedsMax(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE -vCoreMeasurementID INT; - DECLARE -vPrevDBH DECIMAL(10, 2); - DECLARE -vCurrDBH DECIMAL(10, 2); - DECLARE -validationResult BIT; - DECLARE -errorMessage VARCHAR(255); - DECLARE -validationCriteria TEXT; - DECLARE -measuredValue VARCHAR(255); - DECLARE -expectedValueRange VARCHAR(255); - DECLARE -additionalDetails TEXT; - DECLARE -insertCount INT DEFAULT 0; - DECLARE -expectedCount INT; - DECLARE -successMessage VARCHAR(255); - DECLARE -veID INT; - DECLARE -done INT DEFAULT FALSE; - DECLARE -cur CURSOR FOR -SELECT cm2.CoreMeasurementID, cm1.MeasuredDBH, cm2.MeasuredDBH -FROM coremeasurements cm1 - JOIN coremeasurements cm2 - ON cm1.StemID = cm2.StemID - AND YEAR (cm2.MeasurementDate) = YEAR (cm1.MeasurementDate) + 1 - LEFT JOIN stems st -ON cm2.StemID = st.StemID - LEFT JOIN quadrats q ON st.QuadratID = q.QuadratID - LEFT JOIN cmattributes cma - ON cm1.CoreMeasurementID = cma.CoreMeasurementID - LEFT JOIN attributes a - ON cma.Code = a.Code -WHERE (a.Status NOT IN ('dead' - , 'stem dead' - , 'broken below' - , 'missing' - , 'omitted') - OR a.Status IS NULL) - AND cm1.MeasuredDBH IS NOT NULL - AND cm2.MeasuredDBH IS NOT NULL - AND cm1.IsValidated IS TRUE - AND cm2.IsValidated IS FALSE - AND (p_CensusID IS NULL - OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL - OR q.PlotID = p_PlotID); - -DECLARE -CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE -TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF -p_CensusID IS NULL THEN - SET p_CensusID = -1; -END IF; - IF -p_PlotID IS NULL THEN - SET p_PlotID = -1; -END IF; - -SELECT COUNT(*) -INTO expectedCount -FROM coremeasurements cm1 - JOIN coremeasurements cm2 - ON cm1.StemID = cm2.StemID - AND YEAR (cm2.MeasurementDate) = YEAR (cm1.MeasurementDate) + 1 - LEFT JOIN stems st -ON cm2.StemID = st.StemID - LEFT JOIN quadrats q ON st.QuadratID = q.QuadratID - LEFT JOIN cmattributes cma - ON cm1.CoreMeasurementID = cma.CoreMeasurementID - LEFT JOIN attributes a - ON cma.Code = a.Code -WHERE (a.Status NOT IN ('dead' - , 'stem dead' - , 'broken below' - , 'missing' - , 'omitted') - OR a.Status IS NULL) - AND cm1.MeasuredDBH IS NOT NULL - AND cm2.MeasuredDBH IS NOT NULL - AND cm1.IsValidated IS TRUE - AND cm2.IsValidated IS FALSE - AND (p_CensusID IS NULL - OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL - OR q.PlotID = p_PlotID); - -SELECT ValidationID -INTO veID -FROM catalog.validationprocedures -WHERE ProcedureName = 'ValidateDBHShrinkageExceedsMax'; - -OPEN cur; -loop1 -: - LOOP - FETCH cur INTO vCoreMeasurementID, vPrevDBH, vCurrDBH; - IF -done THEN - LEAVE loop1; -END IF; - - SET -validationCriteria = 'Annual DBH Shrinkage'; - SET -measuredValue = CONCAT('Previous DBH: ', vPrevDBH, ', Current DBH: ', vCurrDBH); - SET -expectedValueRange = 'Shrinkage < 5% of previous DBH'; - SET -additionalDetails = 'Checked for excessive DBH shrinkage over a year'; - - IF -vCurrDBH < vPrevDBH * 0.95 THEN - SET validationResult = 0; - SET -errorMessage = 'Shrinkage exceeds maximum allowed threshold.'; - -- Check if the error record already exists before inserting - IF -NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); -END IF; -INSERT INTO FailedValidations (CoreMeasurementID) -VALUES (vCoreMeasurementID); -SET -insertCount = insertCount + 1; -ELSE - SET validationResult = 1; - SET -errorMessage = NULL; -END IF; - -INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) -VALUES ('ValidateDBHShrinkageExceedsMax', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); -END LOOP; -CLOSE cur; - -SET -successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); -SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - -SELECT CoreMeasurementID -FROM FailedValidations; - -DROP -TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create -definer = azureroot@`%` procedure ValidateFindAllInvalidSpeciesCodes(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE -vCoreMeasurementID INT; - DECLARE -vSpeciesID INT; - DECLARE -validationResult BIT; - DECLARE -errorMessage VARCHAR(255); - DECLARE -validationCriteria TEXT; - DECLARE -measuredValue VARCHAR(255); - DECLARE -expectedValueRange VARCHAR(255); - DECLARE -additionalDetails TEXT; - DECLARE -insertCount INT DEFAULT 0; - DECLARE -expectedCount INT; - DECLARE -successMessage VARCHAR(255); - DECLARE -veID INT; - DECLARE -done INT DEFAULT FALSE; - DECLARE -cur CURSOR FOR -SELECT cm.CoreMeasurementID, sp.SpeciesID -FROM stems s - JOIN trees t ON s.TreeID = t.TreeID - LEFT JOIN species sp ON t.SpeciesID = sp.SpeciesID - JOIN coremeasurements cm ON s.StemID = cm.StemID - LEFT JOIN quadrats q ON s.QuadratID = q.QuadratID -WHERE sp.SpeciesID IS NULL - AND cm.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) -GROUP BY cm.CoreMeasurementID; - -DECLARE -CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE -TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF -p_CensusID IS NULL THEN - SET p_CensusID = -1; -END IF; - IF -p_PlotID IS NULL THEN - SET p_PlotID = -1; -END IF; - -SELECT COUNT(*) -INTO expectedCount -FROM stems s - JOIN trees t ON s.TreeID = t.TreeID - LEFT JOIN species sp ON t.SpeciesID = sp.SpeciesID - JOIN coremeasurements cm ON s.StemID = cm.StemID - LEFT JOIN quadrats q ON s.QuadratID = q.QuadratID -WHERE sp.SpeciesID IS NULL - AND cm.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) -GROUP BY cm.CoreMeasurementID; - -SELECT ValidationID -INTO veID -FROM catalog.validationprocedures -WHERE ProcedureName = 'ValidateFindAllInvalidSpeciesCodes'; - -OPEN cur; -loop1 -: - LOOP - FETCH cur INTO vCoreMeasurementID, vSpeciesID; - IF -done THEN - LEAVE loop1; -END IF; - - SET -validationCriteria = 'Species Code Validation'; - SET -measuredValue = CONCAT('Species ID: ', IFNULL(vSpeciesID, 'NULL')); - SET -expectedValueRange = 'Non-null and valid Species ID'; - SET -additionalDetails = 'Checking for the existence of valid species codes for each measurement.'; - - IF -vSpeciesID IS NULL THEN - SET validationResult = 0; - SET -errorMessage = 'Invalid species code detected.'; - -- Check if the error record already exists before inserting - IF -NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); -END IF; -INSERT INTO FailedValidations (CoreMeasurementID) -VALUES (vCoreMeasurementID); -SET -insertCount = insertCount + 1; -ELSE - SET validationResult = 1; - SET -errorMessage = NULL; -END IF; - -INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) -VALUES ('ValidateFindAllInvalidSpeciesCodes', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); -END LOOP; -CLOSE cur; - -SET -successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); -SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - -SELECT CoreMeasurementID -FROM FailedValidations; - -DROP -TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create -definer = azureroot@`%` procedure ValidateFindDuplicateStemTreeTagCombinationsPerCensus(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE -vCoreMeasurementID INT; - DECLARE -validationResult BIT; - DECLARE -errorMessage VARCHAR(255); - DECLARE -validationCriteria TEXT; - DECLARE -measuredValue VARCHAR(255); - DECLARE -expectedValueRange VARCHAR(255); - DECLARE -additionalDetails TEXT; - DECLARE -insertCount INT DEFAULT 0; - DECLARE -expectedCount INT; - DECLARE -successMessage VARCHAR(255); - DECLARE -veID INT; - DECLARE -done INT DEFAULT FALSE; - DECLARE -cur CURSOR FOR -SELECT SubQuery.CoreMeasurementID -FROM (SELECT cm.CoreMeasurementID - FROM coremeasurements cm - INNER JOIN stems s ON cm.StemID = s.StemID - INNER JOIN trees t ON s.TreeID = t.TreeID - INNER JOIN quadrats q ON s.QuadratID = q.QuadratID - WHERE (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) - AND cm.IsValidated = FALSE - GROUP BY q.CensusID, s.StemTag, t.TreeTag, cm.CoreMeasurementID - HAVING COUNT(*) > 1) AS SubQuery; - -DECLARE -CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE -TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF -p_CensusID IS NULL THEN - SET p_CensusID = -1; -END IF; - IF -p_PlotID IS NULL THEN - SET p_PlotID = -1; -END IF; - -SELECT COUNT(*) -INTO expectedCount -FROM (SELECT cm.CoreMeasurementID - FROM coremeasurements cm - INNER JOIN stems s ON cm.StemID = s.StemID - INNER JOIN trees t ON s.TreeID = t.TreeID - INNER JOIN quadrats q ON s.QuadratID = q.QuadratID - WHERE (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) - AND cm.IsValidated = FALSE - GROUP BY q.CensusID, s.StemTag, t.TreeTag, cm.CoreMeasurementID - HAVING COUNT(*) > 1) AS DuplicationCheck; - -SELECT ValidationID -INTO veID -FROM catalog.validationprocedures -WHERE ProcedureName = 'ValidateFindDuplicateStemTreeTagCombinationsPerCensus'; - - -OPEN cur; -loop1 -: - LOOP - FETCH cur INTO vCoreMeasurementID; - IF -done THEN - LEAVE loop1; -END IF; - - SET -validationCriteria = 'Duplicate Stem-Tree Tag Combinations per Census'; - SET -measuredValue = 'N/A'; - SET -expectedValueRange = 'Unique Stem-Tree Tag Combinations'; - SET -additionalDetails = 'Checking for duplicate stem and tree tag combinations in each census.'; - - IF -EXISTS (SELECT 1 - FROM coremeasurements cm - INNER JOIN stems s ON cm.StemID = s.StemID - INNER JOIN trees t ON s.TreeID = t.TreeID - INNER JOIN quadrats q ON s.QuadratID = q.QuadratID - WHERE cm.CoreMeasurementID = vCoreMeasurementID - GROUP BY q.CensusID, s.StemTag, t.TreeTag - HAVING COUNT(cm.CoreMeasurementID) > 1) THEN - SET validationResult = 0; - SET -errorMessage = 'Duplicate stem and tree tag combination detected.'; - -- Check if the error record already exists before inserting - IF -NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); -END IF; -INSERT INTO FailedValidations (CoreMeasurementID) -VALUES (vCoreMeasurementID); -SET -insertCount = insertCount + 1; -ELSE - SET validationResult = 1; - SET -errorMessage = NULL; -END IF; - -INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) -VALUES ('ValidateFindDuplicateStemTreeTagCombinationsPerCensus', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); -END LOOP; -CLOSE cur; - -SET -successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); -SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - -SELECT CoreMeasurementID -FROM FailedValidations; - -DROP -TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create -definer = azureroot@`%` procedure ValidateFindDuplicatedQuadratsByName(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE -vCoreMeasurementID INT; - DECLARE -validationResult BIT; - DECLARE -errorMessage VARCHAR(255); - DECLARE -validationCriteria TEXT; - DECLARE -measuredValue VARCHAR(255); - DECLARE -expectedValueRange VARCHAR(255); - DECLARE -additionalDetails TEXT; - DECLARE -insertCount INT DEFAULT 0; - DECLARE -expectedCount INT; - DECLARE -successMessage VARCHAR(255); - DECLARE -veID INT; - DECLARE -done INT DEFAULT FALSE; - DECLARE -cur CURSOR FOR -SELECT cm.CoreMeasurementID -FROM quadrats q - LEFT JOIN stems st ON q.QuadratID = st.QuadratID - JOIN coremeasurements cm ON st.StemID = cm.StemID -WHERE cm.IsValidated IS FALSE - AND (q.PlotID, q.QuadratName) IN (SELECT PlotID, QuadratName - FROM quadrats - GROUP BY PlotID, QuadratName - HAVING COUNT(*) > 1) - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) -GROUP BY cm.CoreMeasurementID; - -DECLARE -CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE -TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF -p_CensusID IS NULL THEN - SET p_CensusID = -1; -END IF; - IF -p_PlotID IS NULL THEN - SET p_PlotID = -1; -END IF; - -SELECT COUNT(*) -INTO expectedCount -FROM quadrats q - LEFT JOIN stems st ON q.QuadratID = st.QuadratID - JOIN coremeasurements cm ON st.StemID = cm.StemID -WHERE cm.IsValidated IS FALSE - AND (q.PlotID, q.QuadratName) IN (SELECT PlotID, QuadratName - FROM quadrats - GROUP BY PlotID, QuadratName - HAVING COUNT(*) > 1) - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) -GROUP BY cm.CoreMeasurementID; - -SELECT ValidationID -INTO veID -FROM catalog.validationprocedures -WHERE ProcedureName = 'ValidateFindDuplicatedQuadratsByName'; - -OPEN cur; -loop1 -: - LOOP - FETCH cur INTO vCoreMeasurementID; - IF -done THEN - LEAVE loop1; -END IF; - - SET -validationCriteria = 'Quadrat Name Duplication'; - SET -measuredValue = 'N/A'; - SET -expectedValueRange = 'Unique Quadrat Names per Plot'; - SET -additionalDetails = 'Checking for duplicated quadrat names within the same plot.'; - - IF -EXISTS (SELECT 1 - FROM quadrats q - WHERE q.QuadratID = vCoreMeasurementID - AND (q.PlotID, q.QuadratName) IN (SELECT PlotID, QuadratName - FROM quadrats - GROUP BY PlotID, QuadratName - HAVING COUNT(*) > 1)) THEN - SET validationResult = 0; - SET -errorMessage = 'Duplicated quadrat name detected.'; - -- Check if the error record already exists before inserting - IF -NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); -END IF; -INSERT INTO FailedValidations (CoreMeasurementID) -VALUES (vCoreMeasurementID); -SET -insertCount = insertCount + 1; -ELSE - SET validationResult = 1; - SET -errorMessage = NULL; -END IF; - -INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) -VALUES ('ValidateFindDuplicatedQuadratsByName', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); -END LOOP; -CLOSE cur; - -SET -successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); -SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - -SELECT CoreMeasurementID -FROM FailedValidations; - -DROP -TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create -definer = azureroot@`%` procedure ValidateFindMeasurementsOutsideCensusDateBoundsGroupByQuadrat(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE -vCoreMeasurementID INT; - DECLARE -validationResult BIT; - DECLARE -errorMessage VARCHAR(255); - DECLARE -validationCriteria TEXT; - DECLARE -measuredValue VARCHAR(255); - DECLARE -expectedValueRange VARCHAR(255); - DECLARE -additionalDetails TEXT; - DECLARE -insertCount INT DEFAULT 0; - DECLARE -expectedCount INT; - DECLARE -successMessage VARCHAR(255); - DECLARE -veID INT; - DECLARE -done INT DEFAULT FALSE; - DECLARE -cur CURSOR FOR -SELECT MIN(cm.CoreMeasurementID) AS CoreMeasurementID -FROM coremeasurements cm - JOIN stems st ON cm.StemID = st.StemID - JOIN quadrats q ON st.QuadratID = q.QuadratID - JOIN census c ON q.CensusID = c.CensusID -WHERE (cm.MeasurementDate < c.StartDate OR cm.MeasurementDate > c.EndDate) - AND cm.MeasurementDate IS NOT NULL - AND cm.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR c.PlotID = p_PlotID) -GROUP BY q.QuadratID, c.CensusID, c.StartDate, c.EndDate; - -DECLARE -CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE -TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF -p_CensusID IS NULL THEN - SET p_CensusID = -1; -END IF; - IF -p_PlotID IS NULL THEN - SET p_PlotID = -1; -END IF; - -SELECT COUNT(*) -INTO expectedCount -FROM coremeasurements cm - JOIN stems st ON cm.StemID = st.StemID - JOIN quadrats q ON st.QuadratID = q.QuadratID - JOIN census c ON q.CensusID = c.CensusID -WHERE (cm.MeasurementDate < c.StartDate OR cm.MeasurementDate > c.EndDate) - AND cm.MeasurementDate IS NOT NULL - AND cm.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR c.PlotID = p_PlotID); - -SELECT ValidationID -INTO veID -FROM catalog.validationprocedures -WHERE ProcedureName = 'ValidateFindMeasurementsOutsideCensusDateBoundsGroupByQuadrat'; - - -OPEN cur; -loop1 -: - LOOP - FETCH cur INTO vCoreMeasurementID; - IF -done THEN - LEAVE loop1; -END IF; - - SET -validationCriteria = 'Measurement Date vs Census Date Bounds'; - SET -measuredValue = 'Measurement Date'; - SET -expectedValueRange = 'Within Census Start and End Dates'; - SET -additionalDetails = - 'Checking if measurement dates fall within the start and end dates of their respective censuses.'; - - IF -EXISTS (SELECT 1 - FROM coremeasurements cm - JOIN stems st ON cm.StemID = st.StemID - JOIN quadrats q ON st.QuadratID = q.QuadratID - JOIN census c ON q.CensusID = c.CensusID - WHERE cm.CoreMeasurementID = vCoreMeasurementID - AND (cm.MeasurementDate < c.StartDate OR cm.MeasurementDate > c.EndDate)) THEN - SET validationResult = 0; - SET -errorMessage = 'Measurement outside census date bounds.'; - -- Check if the error record already exists before inserting - IF -NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); -END IF; -INSERT INTO FailedValidations (CoreMeasurementID) -VALUES (vCoreMeasurementID); -SET -insertCount = insertCount + 1; -ELSE - SET validationResult = 1; - SET -errorMessage = NULL; -END IF; - -INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) -VALUES ('ValidateFindMeasurementsOutsideCensusDateBoundsGroupByQuadrat', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); -END LOOP; -CLOSE cur; - -SET -successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); -SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - -SELECT CoreMeasurementID -FROM FailedValidations; - -DROP -TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create -definer = azureroot@`%` procedure ValidateFindStemsInTreeWithDifferentSpecies(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE -vCoreMeasurementID INT; - DECLARE -validationResult BIT; - DECLARE -errorMessage VARCHAR(255); - DECLARE -validationCriteria TEXT; - DECLARE -measuredValue VARCHAR(255); - DECLARE -expectedValueRange VARCHAR(255); - DECLARE -additionalDetails TEXT; - DECLARE -insertCount INT DEFAULT 0; - DECLARE -expectedCount INT; - DECLARE -successMessage VARCHAR(255); - DECLARE -veID INT; - DECLARE -done INT DEFAULT FALSE; - - DECLARE -cur CURSOR FOR -SELECT cm.CoreMeasurementID -FROM coremeasurements cm - JOIN stems s ON cm.StemID = s.StemID - JOIN trees t ON s.TreeID = t.TreeID - JOIN quadrats q ON s.QuadratID = q.QuadratID -WHERE cm.IsValidated = FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) -GROUP BY t.TreeID, cm.CoreMeasurementID -HAVING COUNT(DISTINCT t.SpeciesID) > 1; - -DECLARE -CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE -TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF -p_CensusID IS NULL THEN - SET p_CensusID = -1; -END IF; - IF -p_PlotID IS NULL THEN - SET p_PlotID = -1; -END IF; - -SELECT COUNT(*) -INTO expectedCount -FROM coremeasurements cm - JOIN stems s ON cm.StemID = s.StemID - JOIN trees t ON s.TreeID = t.TreeID - JOIN quadrats q ON s.QuadratID = q.QuadratID -WHERE cm.IsValidated = FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) -GROUP BY t.TreeID -HAVING COUNT(DISTINCT t.SpeciesID) > 1; - -SELECT ValidationID -INTO veID -FROM catalog.validationprocedures -WHERE ProcedureName = 'ValidateFindStemsInTreeWithDifferentSpecies'; - - -OPEN cur; -loop1 -: - LOOP - FETCH cur INTO vCoreMeasurementID; - IF -done THEN - LEAVE loop1; -END IF; - - SET -validationCriteria = 'Each tree should have a consistent species across all its stems.'; - SET -measuredValue = 'Species consistency across tree stems'; - SET -expectedValueRange = 'One species per tree'; - SET -additionalDetails = 'Checking if stems belonging to the same tree have different species IDs.'; - - IF -EXISTS (SELECT 1 - FROM stems s - JOIN trees t ON s.TreeID = t.TreeID - WHERE t.TreeID IN (SELECT TreeID - FROM stems - WHERE StemID IN - (SELECT StemID - FROM coremeasurements - WHERE CoreMeasurementID = vCoreMeasurementID)) - GROUP BY t.TreeID - HAVING COUNT(DISTINCT t.SpeciesID) > 1) THEN - SET validationResult = 0; - SET -errorMessage = 'Stems in the same tree have different species.'; - - -- Check if the error record already exists before inserting - IF -NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); -END IF; -INSERT INTO FailedValidations (CoreMeasurementID) -VALUES (vCoreMeasurementID); -SET -insertCount = insertCount + 1; -ELSE - SET validationResult = 1; - SET -errorMessage = NULL; -END IF; - -INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) -VALUES ('ValidateFindStemsInTreeWithDifferentSpecies', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); -END LOOP; -CLOSE cur; - -SET -successMessage = CONCAT('Validation completed. Total rows: ', expectedCount, ', Failed rows: ', insertCount); -SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - -SELECT CoreMeasurementID -FROM FailedValidations; - -DROP -TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create -definer = azureroot@`%` procedure ValidateFindStemsOutsidePlots(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE -vCoreMeasurementID INT; - DECLARE -validationResult BIT; - DECLARE -errorMessage VARCHAR(255); - DECLARE -validationCriteria TEXT; - DECLARE -measuredValue VARCHAR(255); - DECLARE -expectedValueRange VARCHAR(255); - DECLARE -additionalDetails TEXT; - DECLARE -insertCount INT DEFAULT 0; - DECLARE -expectedCount INT; - DECLARE -successMessage VARCHAR(255); - DECLARE -veID INT; - DECLARE -done INT DEFAULT FALSE; - - DECLARE -cur CURSOR FOR -SELECT cm.CoreMeasurementID -FROM stems s - INNER JOIN coremeasurements cm ON s.StemID = cm.StemID - INNER JOIN quadrats q ON s.QuadratID = q.QuadratID - INNER JOIN plots p ON q.PlotID = p.PlotID -WHERE (s.LocalX > p.DimensionX OR s.LocalX > p.DimensionY) - AND s.LocalX IS NOT NULL - AND s.LocalY IS NOT NULL - AND (p.DimensionX > 0 AND p.DimensionY > 0) - AND cm.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID) -GROUP BY cm.CoreMeasurementID; - -DECLARE -CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE -TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF -p_CensusID IS NULL THEN - SET p_CensusID = -1; -END IF; - IF -p_PlotID IS NULL THEN - SET p_PlotID = -1; -END IF; - -SELECT COUNT(*) -INTO expectedCount -FROM stems s - INNER JOIN quadrats q ON s.QuadratID = q.QuadratID - INNER JOIN plots p ON q.PlotID = p.PlotID - INNER JOIN coremeasurements cm ON s.StemID = cm.StemID -WHERE (s.LocalX > p.DimensionX OR s.LocalX > p.DimensionY) - AND s.LocalX IS NOT NULL - AND s.LocalY IS NOT NULL - AND (p.DimensionX > 0 AND p.DimensionY > 0) - AND cm.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - -SELECT ValidationID -INTO veID -FROM catalog.validationprocedures -WHERE ProcedureName = 'ValidateFindStemsOutsidePlots'; - - -OPEN cur; -loop1 -: - LOOP - FETCH cur INTO vCoreMeasurementID; - IF -done THEN - LEAVE loop1; -END IF; - - SET -validationCriteria = 'Stem Placement within Plot Boundaries'; - SET -measuredValue = 'Stem Plot Coordinates'; - SET -expectedValueRange = 'Within Plot Dimensions'; - SET -additionalDetails = 'Validating whether stems are located within the specified plot dimensions.'; - - IF -EXISTS (SELECT 1 - FROM stems s - INNER JOIN quadrats q ON s.QuadratID = q.QuadratID - INNER JOIN plots p ON q.PlotID = p.PlotID - WHERE s.StemID IN - (SELECT StemID - FROM coremeasurements - WHERE CoreMeasurementID = vCoreMeasurementID) - AND (s.LocalX > p.DimensionX OR s.LocalY > p.DimensionY)) THEN - SET validationResult = 0; - SET -errorMessage = 'Stem is outside plot dimensions.'; - -- Check if the error record already exists before inserting - IF -NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); -END IF; -INSERT INTO FailedValidations (CoreMeasurementID) -VALUES (vCoreMeasurementID); -SET -insertCount = insertCount + 1; -ELSE - SET validationResult = 1; - SET -errorMessage = NULL; -END IF; - -INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) -VALUES ('ValidateFindStemsOutsidePlots', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); -END LOOP; -CLOSE cur; - -SET -successMessage = CONCAT('Validation completed. Total rows: ', expectedCount, ', Failed rows: ', insertCount); -SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - -SELECT CoreMeasurementID -FROM FailedValidations; - -DROP -TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create -definer = azureroot@`%` procedure ValidateFindTreeStemsInDifferentQuadrats(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE -vCoreMeasurementID INT; - DECLARE -validationResult BIT; - DECLARE -errorMessage VARCHAR(255); - DECLARE -validationCriteria TEXT; - DECLARE -measuredValue VARCHAR(255); - DECLARE -expectedValueRange VARCHAR(255); - DECLARE -additionalDetails TEXT; - DECLARE -insertCount INT DEFAULT 0; - DECLARE -expectedCount INT; - DECLARE -successMessage VARCHAR(255); - DECLARE -veID INT; - DECLARE -done INT DEFAULT FALSE; - - DECLARE -cur CURSOR FOR -SELECT cm1.CoreMeasurementID -FROM stems s1 - JOIN stems s2 ON s1.TreeID = s2.TreeID AND s1.StemID != s2.StemID - JOIN quadrats q1 -ON s1.QuadratID = q1.QuadratID - JOIN quadrats q2 ON s2.QuadratID = q2.QuadratID - JOIN coremeasurements cm1 ON s1.StemID = cm1.StemID -WHERE q1.QuadratID != q2.QuadratID - AND cm1.IsValidated IS FALSE - AND (p_CensusID IS NULL - OR q1.CensusID = p_CensusID) - AND (p_PlotID IS NULL - OR q1.PlotID = p_PlotID) -GROUP BY cm1.CoreMeasurementID; - -DECLARE -CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE -TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - - IF -p_CensusID IS NULL THEN - SET p_CensusID = -1; -END IF; - IF -p_PlotID IS NULL THEN - SET p_PlotID = -1; -END IF; - -SELECT COUNT(*) -INTO expectedCount -FROM stems s1 - JOIN stems s2 ON s1.TreeID = s2.TreeID AND s1.StemID != s2.StemID - JOIN quadrats q1 -ON s1.QuadratID = q1.QuadratID - JOIN quadrats q2 ON s2.QuadratID = q2.QuadratID - JOIN coremeasurements cm1 ON s1.StemID = cm1.StemID -WHERE q1.QuadratID != q2.QuadratID - AND cm1.IsValidated IS FALSE - AND (p_CensusID IS NULL - OR q1.CensusID = p_CensusID) - AND (p_PlotID IS NULL - OR q1.PlotID = p_PlotID) -GROUP BY cm1.CoreMeasurementID; - -SELECT ValidationID -INTO veID -FROM catalog.validationprocedures -WHERE ProcedureName = 'ValidateFindTreeStemsInDifferentQuadrats'; - - -OPEN cur; -loop1 -: - LOOP - FETCH cur INTO vCoreMeasurementID; - IF -done THEN - LEAVE loop1; -END IF; - - SET -validationCriteria = 'Stem Quadrat Consistency within Trees'; - SET -measuredValue = 'Quadrat IDs of Stems'; - SET -expectedValueRange = 'Consistent Quadrat IDs for all Stems in a Tree'; - SET -additionalDetails = 'Validating that all stems within the same tree are located in the same quadrat.'; - - IF -EXISTS (SELECT 1 - FROM stems s1 - JOIN stems s2 ON s1.TreeID = s2.TreeID AND s1.StemID != s2.StemID - JOIN quadrats q1 on q1.QuadratID = s2.QuadratID - JOIN quadrats q2 on q2.QuadratID = s2.QuadratID - WHERE s1.StemID IN - (SELECT StemID - FROM coremeasurements - WHERE CoreMeasurementID = vCoreMeasurementID) - AND q1.QuadratID != q2.QuadratID) THEN - SET validationResult = 0; - SET -errorMessage = 'Stems in the same tree are in different quadrats.'; - -- Check if the error record already exists before inserting - IF -NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); -END IF; -INSERT INTO FailedValidations (CoreMeasurementID) -VALUES (vCoreMeasurementID); -SET -insertCount = insertCount + 1; -ELSE - SET validationResult = 1; - SET -errorMessage = NULL; -END IF; - -INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) -VALUES ('ValidateFindTreeStemsInDifferentQuadrats', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); -END LOOP; -CLOSE cur; - -SET -successMessage = CONCAT('Validation completed. Total rows: ', expectedCount, ', Failed rows: ', insertCount); -SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - -SELECT CoreMeasurementID -FROM FailedValidations; - -DROP -TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create -definer = azureroot@`%` procedure ValidateHOMUpperAndLowerBounds(IN p_CensusID int, IN p_PlotID int, - IN minHOM decimal(10, 2), IN maxHOM decimal(10, 2)) -BEGIN - DECLARE -defaultMinHOM DECIMAL(10, 2); - DECLARE -defaultMaxHOM DECIMAL(10, 2); - DECLARE -vCoreMeasurementID INT; - DECLARE -validationResult BIT; - DECLARE -errorMessage VARCHAR(255); - DECLARE -validationCriteria TEXT; - DECLARE -measuredValue VARCHAR(255); - DECLARE -expectedValueRange VARCHAR(255); - DECLARE -additionalDetails TEXT; - DECLARE -insertCount INT DEFAULT 0; - DECLARE -expectedCount INT; - DECLARE -successMessage VARCHAR(255); - DECLARE -veID INT; - DECLARE -done INT DEFAULT FALSE; - - DECLARE -cur CURSOR FOR -SELECT cm.CoreMeasurementID -FROM coremeasurements cm - LEFT JOIN stems st ON cm.StemID = st.StemID - LEFT JOIN quadrats q ON st.QuadratID = q.QuadratID -WHERE ( - (minHOM IS NOT NULL AND MeasuredHOM < minHOM) OR - (maxHOM IS NOT NULL AND MeasuredHOM > maxHOM) OR - (minHOM IS NULL AND maxHOM IS NULL) - ) - AND IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - -DECLARE -CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE -TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - -SELECT COUNT(*) -INTO expectedCount -FROM coremeasurements cm - LEFT JOIN stems st ON cm.StemID = st.StemID - LEFT JOIN quadrats q ON st.QuadratID = q.QuadratID -WHERE ( - (minHOM IS NOT NULL AND MeasuredHOM < minHOM) OR - (maxHOM IS NOT NULL AND MeasuredHOM > maxHOM) OR - (minHOM IS NULL AND maxHOM IS NULL) - ) - AND IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - -SELECT ValidationID -INTO veID -FROM catalog.validationprocedures -WHERE ProcedureName = 'ValidateHOMUpperAndLowerBounds'; - - -OPEN cur; -loop1 -: - LOOP - FETCH cur INTO vCoreMeasurementID; - - IF -done THEN - LEAVE loop1; -END IF; - - IF -minHOM IS NULL OR maxHOM IS NULL THEN -SELECT COALESCE(sl.LowerBound, 0) AS defaultMinHOM, - COALESCE(sl.UpperBound, 9999) AS defaultMaxHOM -INTO defaultMinHOM, defaultMaxHOM -FROM specieslimits sl - JOIN species s ON sl.SpeciesCode = s.SpeciesCode - JOIN trees t ON s.SpeciesID = t.SpeciesID - JOIN stems st ON t.TreeID = st.TreeID - JOIN coremeasurements cm ON st.StemID = cm.StemID -WHERE cm.CoreMeasurementID = vCoreMeasurementID - AND sl.LimitType = 'HOM'; - -SET -minHOM = COALESCE(minHOM, defaultMinHOM); - SET -maxHOM = COALESCE(maxHOM, defaultMaxHOM); -END IF; - - SET -validationCriteria = 'HOM Measurement Range Validation'; - SET -measuredValue = CONCAT('Measured HOM: ', (SELECT MeasuredHOM - FROM coremeasurements - WHERE CoreMeasurementID = vCoreMeasurementID)); - SET -expectedValueRange = CONCAT('Expected HOM Range: ', minHOM, ' - ', maxHOM); - SET -additionalDetails = 'Checks if the measured HOM falls within the specified minimum and maximum range.'; - - IF -( -SELECT MeasuredHOM -FROM coremeasurements -WHERE CoreMeasurementID = vCoreMeasurementID - AND ( - (minHOM IS NOT NULL AND MeasuredHOM < minHOM) OR - (maxHOM IS NOT NULL AND MeasuredHOM > maxHOM) OR - (minHOM IS NULL AND maxHOM IS NULL) - ) - ) THEN -SET validationResult = 0; -SET -errorMessage = CONCAT('HOM outside bounds: ', minHOM, ' - ', maxHOM); -INSERT INTO FailedValidations (CoreMeasurementID) -VALUES (vCoreMeasurementID); -SET -insertCount = insertCount + 1; - -- Check if the error record already exists before inserting - IF -NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); -END IF; -ELSE - SET validationResult = 1; - SET -errorMessage = NULL; -END IF; - -INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) -VALUES ('ValidateHOMUpperAndLowerBounds', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); -END LOOP; -CLOSE cur; - -SET -successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); -SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - -SELECT CoreMeasurementID -FROM FailedValidations; - -DROP -TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create -definer = azureroot@`%` procedure ValidateScreenMeasuredDiameterMinMax(IN p_CensusID int, IN p_PlotID int, - IN minDBH decimal(10, 2), - IN maxDBH decimal(10, 2)) -BEGIN - DECLARE -defaultMinDBH DECIMAL(10, 2); - DECLARE -defaultMaxDBH DECIMAL(10, 2); - DECLARE -vCoreMeasurementID INT; - DECLARE -validationResult BIT; - DECLARE -errorMessage VARCHAR(255); - DECLARE -validationCriteria TEXT; - DECLARE -measuredValue VARCHAR(255); - DECLARE -expectedValueRange VARCHAR(255); - DECLARE -additionalDetails TEXT; - DECLARE -insertCount INT DEFAULT 0; - DECLARE -expectedCount INT; - DECLARE -successMessage VARCHAR(255); - DECLARE -veID INT; - DECLARE -done INT DEFAULT FALSE; - - DECLARE -cur CURSOR FOR -SELECT cm.CoreMeasurementID -FROM coremeasurements cm - LEFT JOIN stems st ON cm.StemID = st.StemID - LEFT JOIN quadrats q ON st.QuadratID = q.QuadratID -WHERE ( - (MeasuredDBH < 0) OR - (maxDBH IS NOT NULL AND MeasuredDBH > maxDBH) OR - (minDBH IS NULL AND maxDBH IS NULL) - ) - AND IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - -DECLARE -CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE -TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - -SELECT COUNT(*) -INTO expectedCount -FROM coremeasurements cm - LEFT JOIN stems st ON cm.StemID = st.StemID - LEFT JOIN quadrats q ON st.QuadratID = q.QuadratID -WHERE ( - (MeasuredDBH < 0) OR - (maxDBH IS NOT NULL AND MeasuredDBH > maxDBH) OR - (minDBH IS NULL AND maxDBH IS NULL) - ) - AND IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - -SELECT ValidationID -INTO veID -FROM catalog.validationprocedures -WHERE ProcedureName = 'ValidateScreenMeasuredDiameterMinMax'; - - -OPEN cur; -loop1 -: - LOOP - FETCH cur INTO vCoreMeasurementID; - - IF -done THEN - LEAVE loop1; -END IF; - - IF -minDBH IS NULL OR maxDBH IS NULL THEN -SELECT COALESCE(sl.LowerBound, 0) AS defaultMinDBH, - COALESCE(sl.UpperBound, 9999) AS defaultMaxDBH -INTO defaultMinDBH, defaultMaxDBH -FROM specieslimits sl - JOIN species s ON sl.SpeciesCode = s.SpeciesCode - JOIN trees t ON s.SpeciesID = t.SpeciesID - JOIN stems st ON t.TreeID = st.TreeID - JOIN coremeasurements cm ON st.StemID = cm.StemID -WHERE cm.CoreMeasurementID = vCoreMeasurementID - AND sl.LimitType = 'DBH'; - -SET -minDBH = COALESCE(minDBH, defaultMinDBH); - SET -maxDBH = COALESCE(maxDBH, defaultMaxDBH); -END IF; - - SET -validationCriteria = 'DBH Measurement Range Validation'; - SET -measuredValue = CONCAT('Measured DBH: ', (SELECT MeasuredDBH - FROM coremeasurements - WHERE CoreMeasurementID = vCoreMeasurementID)); - SET -expectedValueRange = CONCAT('Expected DBH Range: ', minDBH, ' - ', maxDBH); - SET -additionalDetails = 'Checks if the measured DBH falls within the specified minimum and maximum range.'; - - IF -( -SELECT MeasuredDBH -FROM coremeasurements -WHERE CoreMeasurementID = vCoreMeasurementID - AND ( - (MeasuredDBH < 0) OR - (maxDBH IS NOT NULL AND MeasuredDBH > maxDBH) OR - (minDBH IS NULL AND maxDBH IS NULL) - ) - ) THEN -SET validationResult = 0; -SET -errorMessage = CONCAT('DBH outside bounds: ', minDBH, ' - ', maxDBH); -INSERT INTO FailedValidations (CoreMeasurementID) -VALUES (vCoreMeasurementID); -SET -insertCount = insertCount + 1; - -- Check if the error record already exists before inserting - IF -NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); -END IF; -ELSE - SET validationResult = 1; - SET -errorMessage = NULL; -END IF; - -INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, MeasuredValue, ExpectedValueRange, - AdditionalDetails) -VALUES ('ValidateScreenMeasuredDiameterMinMax', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, measuredValue, expectedValueRange, - additionalDetails); -END LOOP; -CLOSE cur; - -SET -successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); -SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - -SELECT CoreMeasurementID -FROM FailedValidations; - -DROP -TEMPORARY TABLE IF EXISTS FailedValidations; -END; - -create -definer = azureroot@`%` procedure ValidateScreenStemsWithMeasurementsButDeadAttributes(IN p_CensusID int, IN p_PlotID int) -BEGIN - DECLARE -vCoreMeasurementID INT; - DECLARE -validationResult BIT; - DECLARE -errorMessage VARCHAR(255); - DECLARE -validationCriteria TEXT; - DECLARE -additionalDetails TEXT; - DECLARE -insertCount INT DEFAULT 0; - DECLARE -expectedCount INT; - DECLARE -successMessage VARCHAR(255); - DECLARE -done INT DEFAULT FALSE; - DECLARE -veID INT; - DECLARE -vExistingErrorID INT; - - DECLARE -cur CURSOR FOR -SELECT cm.CoreMeasurementID -FROM coremeasurements cm - JOIN cmattributes cma ON cm.CoreMeasurementID = cma.CoreMeasurementID - JOIN attributes a ON cma.Code = a.Code - JOIN stems st ON cm.StemID = st.StemID - JOIN quadrats q ON st.QuadratID = q.QuadratID -WHERE ((cm.MeasuredDBH IS NOT NULL AND cm.MeasuredDBH > 0) OR - (cm.MeasuredHOM IS NOT NULL AND cm.MeasuredHOM > 0)) - AND a.Status IN ('dead', 'stem dead', 'missing', 'broken below', 'omitted') - AND cm.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - -DECLARE -CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; - - CREATE -TEMPORARY TABLE IF NOT EXISTS FailedValidations - ( - CoreMeasurementID INT - ); - -SELECT COUNT(*) -INTO expectedCount -FROM coremeasurements cm - JOIN cmattributes cma ON cm.CoreMeasurementID = cma.CoreMeasurementID - JOIN attributes a ON cma.Code = a.Code - JOIN stems st ON cm.StemID = st.StemID - JOIN quadrats q ON st.QuadratID = q.QuadratID -WHERE ((cm.MeasuredDBH IS NOT NULL AND cm.MeasuredDBH > 0) OR - (cm.MeasuredHOM IS NOT NULL AND cm.MeasuredHOM > 0)) - AND a.Status IN ('dead', 'stem dead', 'missing', 'broken below', 'omitted') - AND cm.IsValidated IS FALSE - AND (p_CensusID IS NULL OR q.CensusID = p_CensusID) - AND (p_PlotID IS NULL OR q.PlotID = p_PlotID); - -SELECT ValidationID -INTO veID -FROM catalog.validationprocedures -WHERE ProcedureName = 'ValidateScreenStemsWithMeasurementsButDeadAttributes'; - - -OPEN cur; -loop1 -: - LOOP - FETCH cur INTO vCoreMeasurementID; - IF -done THEN - LEAVE loop1; -END IF; - - SET -validationCriteria = 'Stem Measurements with Dead Attributes Validation'; - SET -additionalDetails = 'Verifies that stems marked as dead do not have active measurements.'; - - IF -EXISTS (SELECT 1 - FROM cmattributes cma - JOIN attributes a ON cma.Code = a.Code - JOIN coremeasurements cm on cma.CoreMeasurementID = cm.CoreMeasurementID - WHERE cma.CoreMeasurementID = vCoreMeasurementID - AND a.Status IN ('dead', 'stem dead', 'missing', 'broken below', 'omitted') - AND ((cm.MeasuredDBH IS NOT NULL AND cm.MeasuredDBH > 0) OR - (cm.MeasuredHOM IS NOT NULL AND cm.MeasuredHOM > 0))) THEN - SET validationResult = 0; - SET -errorMessage = 'Stem with measurements but dead attributes detected.'; - -- Check if the error record already exists before inserting - IF -NOT EXISTS (SELECT 1 - FROM cmverrors - WHERE CoreMeasurementID = vCoreMeasurementID - AND ValidationErrorID = veID) THEN - INSERT INTO cmverrors (CoreMeasurementID, ValidationErrorID) - VALUES (vCoreMeasurementID, veID); -END IF; -INSERT INTO FailedValidations (CoreMeasurementID) -VALUES (vCoreMeasurementID); -SET -insertCount = insertCount + 1; -ELSE - SET validationResult = 1; - SET -errorMessage = NULL; -END IF; - -INSERT INTO validationchangelog (ProcedureName, RunDateTime, TargetRowID, - ValidationOutcome, ErrorMessage, - ValidationCriteria, AdditionalDetails) -VALUES ('ValidateScreenStemsWithMeasurementsButDeadAttributes', NOW(), vCoreMeasurementID, - IF(validationResult, 'Passed', 'Failed'), errorMessage, - validationCriteria, additionalDetails); -END LOOP; -CLOSE cur; - -SET -successMessage = - CONCAT('Validation completed successfully. Total rows: ', expectedCount, ', Failed rows: ', insertCount); -SELECT expectedCount AS TotalRows, insertCount AS FailedRows, successMessage AS Message; - -SELECT CoreMeasurementID -FROM FailedValidations; - -DROP -TEMPORARY TABLE IF EXISTS FailedValidations; -END; - diff --git a/frontend/sqlscripting/migration-OoO/8-recreaterefreshtriggers.sql b/frontend/sqlscripting/migration-OoO/8-recreaterefreshtriggers.sql deleted file mode 100644 index 32b39d5b..00000000 --- a/frontend/sqlscripting/migration-OoO/8-recreaterefreshtriggers.sql +++ /dev/null @@ -1,401 +0,0 @@ --- DEPRECATED. Skip this step. - --- Create triggers for coremeasurements -CREATE TRIGGER trg_coremeasurements_set_refresh_needed_after_insert - AFTER INSERT - ON coremeasurements - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_coremeasurements_set_refresh_needed_after_update - AFTER UPDATE - ON coremeasurements - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_coremeasurements_set_refresh_needed_after_delete - AFTER DELETE - ON coremeasurements - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for stems -CREATE TRIGGER trg_stems_set_refresh_needed_after_insert - AFTER INSERT - ON stems - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_stems_set_refresh_needed_after_update - AFTER UPDATE - ON stems - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_stems_set_refresh_needed_after_delete - AFTER DELETE - ON stems - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for trees -CREATE TRIGGER trg_trees_set_refresh_needed_after_insert - AFTER INSERT - ON trees - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_trees_set_refresh_needed_after_update - AFTER UPDATE - ON trees - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_trees_set_refresh_needed_after_delete - AFTER DELETE - ON trees - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for species -CREATE TRIGGER trg_species_set_refresh_needed_after_insert - AFTER INSERT - ON species - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_species_set_refresh_needed_after_update - AFTER UPDATE - ON species - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_species_set_refresh_needed_after_delete - AFTER DELETE - ON species - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for quadrats -CREATE TRIGGER trg_quadrats_set_refresh_needed_after_insert - AFTER INSERT - ON quadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_quadrats_set_refresh_needed_after_update - AFTER UPDATE - ON quadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_quadrats_set_refresh_needed_after_delete - AFTER DELETE - ON quadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for census -CREATE TRIGGER trg_census_set_refresh_needed_after_insert - AFTER INSERT - ON census - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_census_set_refresh_needed_after_update - AFTER UPDATE - ON census - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_census_set_refresh_needed_after_delete - AFTER DELETE - ON census - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for cmattributes -CREATE TRIGGER trg_cmattributes_set_refresh_needed_after_insert - AFTER INSERT - ON cmattributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_cmattributes_set_refresh_needed_after_update - AFTER UPDATE - ON cmattributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_cmattributes_set_refresh_needed_after_delete - AFTER DELETE - ON cmattributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for plots -CREATE TRIGGER trg_plots_set_refresh_needed_after_insert - AFTER INSERT - ON plots - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_plots_set_refresh_needed_after_update - AFTER UPDATE - ON plots - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_plots_set_refresh_needed_after_delete - AFTER DELETE - ON plots - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for subquadrats -CREATE TRIGGER trg_subquadrats_set_refresh_needed_after_insert - AFTER INSERT - ON subquadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_subquadrats_set_refresh_needed_after_update - AFTER UPDATE - ON subquadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_subquadrats_set_refresh_needed_after_delete - AFTER DELETE - ON subquadrats - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for roles -CREATE TRIGGER trg_roles_set_refresh_needed_after_insert - AFTER INSERT - ON roles - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_roles_set_refresh_needed_after_update - AFTER UPDATE - ON roles - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_roles_set_refresh_needed_after_delete - AFTER DELETE - ON roles - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for attributes -CREATE TRIGGER trg_attributes_set_refresh_needed_after_insert - AFTER INSERT - ON attributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_attributes_set_refresh_needed_after_update - AFTER UPDATE - ON attributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_attributes_set_refresh_needed_after_delete - AFTER DELETE - ON attributes - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for genus -CREATE TRIGGER trg_genus_set_refresh_needed_after_insert - AFTER INSERT - ON genus - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_genus_set_refresh_needed_after_update - AFTER UPDATE - ON genus - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_genus_set_refresh_needed_after_delete - AFTER DELETE - ON genus - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for family -CREATE TRIGGER trg_family_set_refresh_needed_after_insert - AFTER INSERT - ON family - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_family_set_refresh_needed_after_update - AFTER UPDATE - ON family - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_family_set_refresh_needed_after_delete - AFTER DELETE - ON family - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for specieslimits -CREATE TRIGGER trg_specieslimits_set_refresh_needed_after_insert - AFTER INSERT - ON specieslimits - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_specieslimits_set_refresh_needed_after_update - AFTER UPDATE - ON specieslimits - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_specieslimits_set_refresh_needed_after_delete - AFTER DELETE - ON specieslimits - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for quadratpersonnel -CREATE TRIGGER trg_quadratpersonnel_set_refresh_needed_after_insert - AFTER INSERT - ON quadratpersonnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_quadratpersonnel_set_refresh_needed_after_update - AFTER UPDATE - ON quadratpersonnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_quadratpersonnel_set_refresh_needed_after_delete - AFTER DELETE - ON quadratpersonnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - --- Create triggers for personnel -CREATE TRIGGER trg_personnel_set_refresh_needed_after_insert - AFTER INSERT - ON personnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_personnel_set_refresh_needed_after_update - AFTER UPDATE - ON personnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; - -CREATE TRIGGER trg_personnel_set_refresh_needed_after_delete - AFTER DELETE - ON personnel - FOR EACH ROW -BEGIN - UPDATE batchprocessingflag SET needs_refresh = TRUE WHERE flag_status = 'STARTED'; -END; diff --git a/frontend/sqlscripting/migration_no_mapping.sql b/frontend/sqlscripting/migration_no_mapping.sql index 8a01a01e..d2c58c35 100644 --- a/frontend/sqlscripting/migration_no_mapping.sql +++ b/frontend/sqlscripting/migration_no_mapping.sql @@ -38,9 +38,9 @@ SELECT s.PlotID, IF(s.GUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), s.GUOM, 'm'), s.ShapeOfSite, LEFT(s.DescriptionOfSite, 65535) -FROM stable_panama.Site s - LEFT JOIN stable_panama.Country c ON s.CountryID = c.CountryID - LEFT JOIN stable_panama.Coordinates co ON s.PlotID = co.PlotID +FROM stable_mpala.Site s + LEFT JOIN stable_mpala.Country c ON s.CountryID = c.CountryID + LEFT JOIN stable_mpala.Coordinates co ON s.PlotID = co.PlotID GROUP BY s.PlotID, s.PlotName, s.LocationName, c.CountryName, s.QDimX, s.QDimY, s.PUOM, s.Area, s.GUOM, co.GX, co.GY, co.GZ, s.ShapeOfSite, s.DescriptionOfSite ON DUPLICATE KEY UPDATE PlotName = IF(VALUES(PlotName) != '', VALUES(PlotName), plots.PlotName), @@ -66,7 +66,7 @@ SELECT r.ReferenceID, r.FullReference, IF(CAST(r.DateofPublication AS CHAR) = '0000-00-00', NULL, r.DateofPublication) AS DateOfPublication, NULL -FROM stable_panama.reference r +FROM stable_mpala.reference r ON DUPLICATE KEY UPDATE PublicationTitle = IF(VALUES(PublicationTitle) != '', VALUES(PublicationTitle), reference.PublicationTitle), FullReference = IF(VALUES(FullReference) != '', VALUES(FullReference), @@ -76,14 +76,14 @@ ON DUPLICATE KEY UPDATE PublicationTitle = IF(VALUES(PublicationTitle -- Insert into family with ON DUPLICATE KEY UPDATE INSERT INTO family (FamilyID, Family, ReferenceID) SELECT f.FamilyID, f.Family, f.ReferenceID -FROM stable_panama.family f +FROM stable_mpala.family f ON DUPLICATE KEY UPDATE Family = IF(VALUES(Family) != '', VALUES(Family), family.Family), ReferenceID = VALUES(ReferenceID); -- Insert into genus with ON DUPLICATE KEY UPDATE INSERT INTO genus (GenusID, FamilyID, Genus, ReferenceID, GenusAuthority) SELECT g.GenusID, g.FamilyID, g.Genus, g.ReferenceID, g.Authority -FROM stable_panama.genus g +FROM stable_mpala.genus g ON DUPLICATE KEY UPDATE FamilyID = VALUES(FamilyID), Genus = IF(VALUES(Genus) != '', VALUES(Genus), genus.Genus), ReferenceID = VALUES(ReferenceID), @@ -104,9 +104,9 @@ SELECT sp.SpeciesID, LEFT(sp.Description, 65535), NULL, sp.ReferenceID -FROM stable_panama.species sp - LEFT JOIN stable_panama.subspecies subs ON sp.SpeciesID = subs.SpeciesID - LEFT JOIN stable_panama.reference ref ON sp.ReferenceID = ref.ReferenceID +FROM stable_mpala.species sp + LEFT JOIN stable_mpala.subspecies subs ON sp.SpeciesID = subs.SpeciesID + LEFT JOIN stable_mpala.reference ref ON sp.ReferenceID = ref.ReferenceID GROUP BY sp.SpeciesID, sp.GenusID, sp.Mnemonic, sp.IDLevel, sp.Authority, sp.FieldFamily, sp.Description, sp.ReferenceID ON DUPLICATE KEY UPDATE GenusID = VALUES(GenusID), SpeciesCode = VALUES(SpeciesCode), @@ -124,7 +124,7 @@ ON DUPLICATE KEY UPDATE GenusID = VALUES(GenusID), ReferenceID = VALUES(ReferenceID); -- First, update the census table for any invalid StartDate entries -UPDATE stable_panama.census +UPDATE stable_mpala.census SET StartDate = NULL WHERE CAST(StartDate AS CHAR(10)) = '0000-00-00'; @@ -141,13 +141,9 @@ FROM ( -- Combine census and censusbackup using UNION SELECT CensusID, PlotID, StartDate, EndDate, Description, PlotCensusNumber - FROM stable_panama.census - UNION - SELECT - CensusID, PlotID, StartDate, EndDate, Description, PlotCensusNumber - FROM stable_panama.censusbackup + FROM stable_mpala.census ) c -LEFT JOIN stable_panama.dbh d ON c.CensusID = d.CensusID +LEFT JOIN stable_mpala.dbh d ON c.CensusID = d.CensusID GROUP BY c.CensusID, c.PlotID, @@ -165,7 +161,7 @@ ON DUPLICATE KEY UPDATE -- Insert into roles table INSERT INTO roles (RoleID, RoleName, RoleDescription) SELECT RoleID, Description, NULL -FROM stable_panama.rolereference +FROM stable_mpala.rolereference ON DUPLICATE KEY UPDATE RoleName = VALUES(RoleName), RoleDescription = VALUES(RoleDescription); @@ -178,11 +174,11 @@ SELECT p.LastName, pr.RoleID FROM - stable_panama.personnel p + stable_mpala.personnel p CROSS JOIN - stable_panama.census c + stable_mpala.census c JOIN - stable_panama.personnelrole pr ON p.PersonnelID = pr.PersonnelID; + stable_mpala.personnelrole pr ON p.PersonnelID = pr.PersonnelID; -- Step 2: Insert into personnel from the temporary table, handling duplicates INSERT INTO personnel (CensusID, FirstName, LastName, RoleID) @@ -199,12 +195,18 @@ ON DUPLICATE KEY UPDATE -- Step 3: Drop the temporary table DROP TEMPORARY TABLE tmp_personnel; +-- Insert into censusquadrat with ON DUPLICATE KEY UPDATE +INSERT INTO censusquadrat (CensusID, QuadratID) +SELECT CensusID, QuadratID +FROM stable_mpala.censusquadrat +ON DUPLICATE KEY UPDATE CensusID = VALUES(CensusID), + QuadratID = VALUES (QuadratID); + -- Insert into quadrats with ON DUPLICATE KEY UPDATE -INSERT INTO quadrats (QuadratID, PlotID, CensusID, QuadratName, StartX, StartY, DimensionX, DimensionY, DimensionUnits, +INSERT INTO quadrats (QuadratID, PlotID, QuadratName, StartX, StartY, DimensionX, DimensionY, DimensionUnits, Area, AreaUnits, QuadratShape, CoordinateUnits) SELECT q.QuadratID, q.PlotID, - cq.CensusID, LEFT(q.QuadratName, 65535), MIN(co.PX), MIN(co.PY), @@ -215,13 +217,12 @@ SELECT q.QuadratID, IF(s.QUOM IN ('km2', 'hm2', 'dam2', 'm2', 'dm2', 'cm2', 'mm2'), s.QUOM, 'm2'), IF(q.IsStandardShape = 'Y', 'standard', 'not standard'), IF(s.GUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), s.GUOM, 'm') -FROM stable_panama.quadrat q - LEFT JOIN stable_panama.censusquadrat cq ON q.QuadratID = cq.QuadratID - LEFT JOIN stable_panama.Coordinates co ON q.QuadratID = co.QuadratID - LEFT JOIN stable_panama.Site s ON q.PlotID = s.PlotID -GROUP BY q.QuadratID, q.PlotID, cq.CensusID, q.QuadratName, s.QDimX, s.QDimY, s.QUOM, q.Area, q.IsStandardShape, s.GUOM +FROM stable_mpala.quadrat q + LEFT JOIN stable_mpala.censusquadrat cq ON q.QuadratID = cq.QuadratID + LEFT JOIN stable_mpala.Coordinates co ON q.QuadratID = co.QuadratID + LEFT JOIN stable_mpala.Site s ON q.PlotID = s.PlotID +GROUP BY q.QuadratID, q.PlotID, q.QuadratName, s.QDimX, s.QDimY, s.QUOM, q.Area, q.IsStandardShape, s.GUOM ON DUPLICATE KEY UPDATE PlotID = VALUES(PlotID), - CensusID = VALUES(CensusID), QuadratName = IF(VALUES(QuadratName) != '', VALUES(QuadratName), quadrats.QuadratName), StartX = VALUES(StartX), StartY = VALUES(StartY), @@ -236,7 +237,7 @@ ON DUPLICATE KEY UPDATE PlotID = VALUES(PlotID), -- Insert into trees with ON DUPLICATE KEY UPDATE INSERT INTO trees (TreeID, TreeTag, SpeciesID) SELECT t.TreeID, t.Tag, t.SpeciesID -FROM stable_panama.tree t +FROM stable_mpala.tree t ON DUPLICATE KEY UPDATE TreeTag = IF(VALUES(TreeTag) != '', VALUES(TreeTag), trees.TreeTag), SpeciesID = VALUES(SpeciesID); @@ -253,9 +254,9 @@ SELECT s.StemID, IF(si.QUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), si.QUOM, 'm') AS CoordinateUnits, IF(s.Moved = 'Y', 1, 0) AS Moved, LEFT(s.StemDescription, 65535) -FROM stable_panama.stem s - LEFT JOIN stable_panama.quadrat q ON q.QuadratID = s.QuadratID - LEFT JOIN stable_panama.Site si ON q.PlotID = si.PlotID +FROM stable_mpala.stem s + LEFT JOIN stable_mpala.quadrat q ON q.QuadratID = s.QuadratID + LEFT JOIN stable_mpala.Site si ON q.PlotID = si.PlotID GROUP BY s.StemID, s.TreeID, s.QuadratID, s.StemNumber, s.StemTag, s.Moved, s.StemDescription, si.QUOM ON DUPLICATE KEY UPDATE TreeID = VALUES(TreeID), QuadratID = VALUES(QuadratID), @@ -287,11 +288,7 @@ FROM ( -- Combine dbh and dbhbackup using UNION SELECT DBHID, CensusID, StemID, DBH, HOM, ExactDate, Comments - FROM stable_panama.dbh - UNION - SELECT - DBHID, CensusID, StemID, DBH, HOM, ExactDate, Comments - FROM stable_panama.dbhbackup + FROM stable_mpala.dbh ) dbh ON DUPLICATE KEY UPDATE StemID = VALUES(StemID), @@ -309,8 +306,8 @@ ON DUPLICATE KEY UPDATE -- Insert into quadratpersonnel with ON DUPLICATE KEY UPDATE INSERT INTO quadratpersonnel (QuadratPersonnelID, QuadratID, PersonnelID, CensusID) SELECT dc.DataCollectionID, dc.QuadratID, pr.PersonnelID, dc.CensusID -FROM stable_panama.datacollection dc - JOIN stable_panama.personnelrole pr ON dc.PersonnelRoleID = pr.PersonnelRoleID +FROM stable_mpala.datacollection dc + JOIN stable_mpala.personnelrole pr ON dc.PersonnelRoleID = pr.PersonnelRoleID ON DUPLICATE KEY UPDATE QuadratID = VALUES(QuadratID), PersonnelID = VALUES(PersonnelID), CensusID = VALUES(CensusID); @@ -321,7 +318,7 @@ SELECT ta.TSMCode, LEFT(ta.Description, 65535), IF(ta.Status IN ('alive', 'alive-not measured', 'dead', 'stem dead', 'broken below', 'omitted', 'missing'), ta.Status, NULL) -FROM stable_panama.tsmattributes ta +FROM stable_mpala.tsmattributes ta GROUP BY ta.TSMCode, ta.Description, ta.Status ON DUPLICATE KEY UPDATE Description = IF(VALUES(Description) != '', VALUES(Description), attributes.Description), Status = VALUES(Status); @@ -336,13 +333,9 @@ FROM ( -- Combine dbhattributes and dbhattributes_backup using UNION SELECT DBHAttID, DBHID, TSMID - FROM stable_panama.dbhattributes - UNION - SELECT - DBHAttID, DBHID, TSMID - FROM stable_panama.dbhattributes_backup + FROM stable_mpala.dbhattributes ) dbha -JOIN stable_panama.tsmattributes ta ON dbha.TSMID = ta.TSMID +JOIN stable_mpala.tsmattributes ta ON dbha.TSMID = ta.TSMID ON DUPLICATE KEY UPDATE CoreMeasurementID = VALUES(CoreMeasurementID), Code = VALUES(Code); @@ -360,9 +353,9 @@ SELECT sp.SpecimenID, sp.CollectionDate, sp.DeterminedBy, LEFT(sp.Description, 65535) -FROM stable_panama.specimen sp - LEFT JOIN stable_panama.stem st ON st.TreeID = sp.TreeID - LEFT JOIN stable_panama.personnel pr ON sp.Collector = CONCAT(pr.FirstName, ' ', pr.LastName) +FROM stable_mpala.specimen sp + LEFT JOIN stable_mpala.stem st ON st.TreeID = sp.TreeID + LEFT JOIN stable_mpala.personnel pr ON sp.Collector = CONCAT(pr.FirstName, ' ', pr.LastName) ON DUPLICATE KEY UPDATE StemID = VALUES(StemID), PersonnelID = VALUES(PersonnelID), SpecimenNumber = VALUES(SpecimenNumber), diff --git a/frontend/sqlscripting/migrationbackup.sql b/frontend/sqlscripting/migrationbackup.sql deleted file mode 100644 index a4926c84..00000000 --- a/frontend/sqlscripting/migrationbackup.sql +++ /dev/null @@ -1,470 +0,0 @@ -SET foreign_key_checks = 0; -truncate attributes; -truncate census; -truncate cmattributes; -truncate cmverrors; -truncate coremeasurements; -truncate family; -truncate genus; -truncate personnel; -truncate plots; -truncate quadratpersonnel; -truncate quadrats; -truncate reference; -truncate roles; -truncate species; -truncate specieslimits; -truncate specimens; -truncate stems; -truncate subquadrats; -truncate unifiedchangelog; -truncate validationchangelog; - -DROP VIEW IF EXISTS `alltaxonomiesview`; -DROP VIEW IF EXISTS `measurementssummaryview`; -DROP VIEW IF EXISTS `stemtaxonomiesview`; -DROP VIEW IF EXISTS `viewfulltableview`; - -DROP PROCEDURE IF EXISTS `UpdateValidationStatus`; -DROP PROCEDURE IF EXISTS `ValidateDBHGrowthExceedsMax`; -DROP PROCEDURE IF EXISTS `ValidateDBHShrinkageExceedsMax`; -DROP PROCEDURE IF EXISTS `ValidateFindAllInvalidSpeciesCodes`; -DROP PROCEDURE IF EXISTS `ValidateFindDuplicatedQuadratsByName`; -DROP PROCEDURE IF EXISTS `ValidateFindDuplicateStemTreeTagCombinationsPerCensus`; -DROP PROCEDURE IF EXISTS `ValidateFindMeasurementsOutsideCensusDateBoundsGroupByQuadrat`; -DROP PROCEDURE IF EXISTS `ValidateFindStemsInTreeWithDifferentSpecies`; -DROP PROCEDURE IF EXISTS `ValidateFindStemsOutsidePlots`; -DROP PROCEDURE IF EXISTS `ValidateFindTreeStemsInDifferentQuadrats`; -DROP PROCEDURE IF EXISTS `ValidateHOMUpperAndLowerBounds`; -DROP PROCEDURE IF EXISTS `ValidateScreenMeasuredDiameterMinMax`; -DROP PROCEDURE IF EXISTS `ValidateScreenStemsWithMeasurementsButDeadAttributes`; - -# attributes -DROP TRIGGER IF EXISTS after_insert_attributes; -DROP TRIGGER IF EXISTS after_update_attributes; -DROP TRIGGER IF EXISTS after_delete_attributes; - -# census -DROP TRIGGER IF EXISTS after_insert_census; -DROP TRIGGER IF EXISTS after_update_census; -DROP TRIGGER IF EXISTS after_delete_census; - -# cmattributes -DROP TRIGGER IF EXISTS after_insert_cmattributes; -DROP TRIGGER IF EXISTS after_update_cmattributes; -DROP TRIGGER IF EXISTS after_delete_cmattributes; - -# cmverrors -DROP TRIGGER IF EXISTS after_insert_cmverrors; -DROP TRIGGER IF EXISTS after_update_cmverrors; -DROP TRIGGER IF EXISTS after_delete_cmverrors; - -# coremeasurements -DROP TRIGGER IF EXISTS after_insert_coremeasurements; -DROP TRIGGER IF EXISTS after_update_coremeasurements; -DROP TRIGGER IF EXISTS after_delete_coremeasurements; - -# family -DROP TRIGGER IF EXISTS after_insert_family; -DROP TRIGGER IF EXISTS after_update_family; -DROP TRIGGER IF EXISTS after_delete_family; - -# genus -DROP TRIGGER IF EXISTS after_insert_genus; -DROP TRIGGER IF EXISTS after_update_genus; -DROP TRIGGER IF EXISTS after_delete_genus; - -# personnel -DROP TRIGGER IF EXISTS after_insert_personnel; -DROP TRIGGER IF EXISTS after_update_personnel; -DROP TRIGGER IF EXISTS after_delete_personnel; - -# plots -DROP TRIGGER IF EXISTS after_insert_plots; -DROP TRIGGER IF EXISTS after_update_plots; -DROP TRIGGER IF EXISTS after_delete_plots; - -# quadratpersonnel -DROP TRIGGER IF EXISTS after_insert_quadratpersonnel; -DROP TRIGGER IF EXISTS after_update_quadratpersonnel; -DROP TRIGGER IF EXISTS after_delete_quadratpersonnel; - -# quadrats -DROP TRIGGER IF EXISTS after_insert_quadrats; -DROP TRIGGER IF EXISTS after_update_quadrats; -DROP TRIGGER IF EXISTS after_delete_quadrats; - -# reference -DROP TRIGGER IF EXISTS after_insert_reference; -DROP TRIGGER IF EXISTS after_update_reference; -DROP TRIGGER IF EXISTS after_delete_reference; - -# roles -DROP TRIGGER IF EXISTS after_insert_roles; -DROP TRIGGER IF EXISTS after_update_roles; -DROP TRIGGER IF EXISTS after_delete_roles; - -# species -DROP TRIGGER IF EXISTS after_insert_species; -DROP TRIGGER IF EXISTS after_update_species; -DROP TRIGGER IF EXISTS after_delete_species; - -# specieslimits -DROP TRIGGER IF EXISTS after_insert_specieslimits; -DROP TRIGGER IF EXISTS after_update_specieslimits; -DROP TRIGGER IF EXISTS after_delete_specieslimits; - -# specimens -DROP TRIGGER IF EXISTS after_insert_specimens; -DROP TRIGGER IF EXISTS after_update_specimens; -DROP TRIGGER IF EXISTS after_delete_specimens; - -# stems -DROP TRIGGER IF EXISTS after_insert_stems; -DROP TRIGGER IF EXISTS after_update_stems; -DROP TRIGGER IF EXISTS after_delete_stems; - -# subquadrats -DROP TRIGGER IF EXISTS after_insert_subquadrats; -DROP TRIGGER IF EXISTS after_update_subquadrats; -DROP TRIGGER IF EXISTS after_delete_subquadrats; - -# trees -DROP TRIGGER IF EXISTS after_insert_trees; -DROP TRIGGER IF EXISTS after_update_trees; -DROP TRIGGER IF EXISTS after_delete_trees; - -# validationchangelog -DROP TRIGGER IF EXISTS after_insert_validationchangelog; -DROP TRIGGER IF EXISTS after_update_validationchangelog; -DROP TRIGGER IF EXISTS after_delete_validationchangelog; - --- Insert into plots with ON DUPLICATE KEY UPDATE -INSERT INTO plots (PlotID, PlotName, LocationName, CountryName, DimensionX, DimensionY, DimensionUnits, Area, AreaUnits, - GlobalX, GlobalY, GlobalZ, CoordinateUnits, PlotShape, PlotDescription) -SELECT s.PlotID, - LEFT(s.PlotName, 65535), - LEFT(s.LocationName, 65535), - c.CountryName, - s.QDimX, - s.QDimY, - IF(s.PUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), s.PUOM, 'm'), - s.Area, - 'm2', - co.GX, - co.GY, - co.GZ, - IF(s.GUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), s.GUOM, 'm'), - s.ShapeOfSite, - LEFT(s.DescriptionOfSite, 65535) -FROM stable_panama.Site s - LEFT JOIN stable_panama.Country c ON s.CountryID = c.CountryID - LEFT JOIN stable_panama.Coordinates co ON s.PlotID = co.PlotID -GROUP BY s.PlotID, s.PlotName, s.LocationName, c.CountryName, s.QDimX, s.QDimY, s.PUOM, s.Area, s.GUOM, co.GX, co.GY, - co.GZ, s.ShapeOfSite, s.DescriptionOfSite -ON DUPLICATE KEY UPDATE PlotName = IF(VALUES(PlotName) != '', VALUES(PlotName), plots.PlotName), - LocationName = IF(VALUES(LocationName) != '', VALUES(LocationName), plots.LocationName), - CountryName = IF(VALUES(CountryName) != '', VALUES(CountryName), plots.CountryName), - DimensionX = VALUES(DimensionX), - DimensionY = VALUES(DimensionY), - DimensionUnits = VALUES(DimensionUnits), - Area = VALUES(Area), - AreaUnits = VALUES(AreaUnits), - GlobalX = VALUES(GlobalX), - GlobalY = VALUES(GlobalY), - GlobalZ = VALUES(GlobalZ), - CoordinateUnits = VALUES(CoordinateUnits), - PlotShape = VALUES(PlotShape), - PlotDescription = IF(VALUES(PlotDescription) != '', VALUES(PlotDescription), - plots.PlotDescription); - --- Insert into reference with ON DUPLICATE KEY UPDATE and handling '0000-00-00' dates -INSERT INTO reference (ReferenceID, PublicationTitle, FullReference, DateOfPublication, Citation) -SELECT r.ReferenceID, - r.PublicationTitle, - r.FullReference, - IF(CAST(r.DateofPublication AS CHAR) = '0000-00-00', NULL, r.DateofPublication) AS DateOfPublication, - NULL -FROM stable_panama.reference r -ON DUPLICATE KEY UPDATE PublicationTitle = IF(VALUES(PublicationTitle) != '', VALUES(PublicationTitle), - reference.PublicationTitle), - FullReference = IF(VALUES(FullReference) != '', VALUES(FullReference), - reference.FullReference), - reference.DateOfPublication = VALUES(DateOfPublication); - --- Insert into family with ON DUPLICATE KEY UPDATE -INSERT INTO family (FamilyID, Family, ReferenceID) -SELECT f.FamilyID, f.Family, f.ReferenceID -FROM stable_panama.family f -ON DUPLICATE KEY UPDATE Family = IF(VALUES(Family) != '', VALUES(Family), family.Family), - ReferenceID = VALUES(ReferenceID); - --- Insert into genus with ON DUPLICATE KEY UPDATE -INSERT INTO genus (GenusID, FamilyID, Genus, ReferenceID, GenusAuthority) -SELECT g.GenusID, g.FamilyID, g.Genus, g.ReferenceID, g.Authority -FROM stable_panama.genus g -ON DUPLICATE KEY UPDATE FamilyID = VALUES(FamilyID), - Genus = IF(VALUES(Genus) != '', VALUES(Genus), genus.Genus), - ReferenceID = VALUES(ReferenceID), - GenusAuthority = IF(VALUES(GenusAuthority) != '', VALUES(GenusAuthority), genus.GenusAuthority); - --- Insert into species with ON DUPLICATE KEY UPDATE -INSERT INTO species (SpeciesID, GenusID, SpeciesCode, SpeciesName, SubspeciesName, IDLevel, SpeciesAuthority, - SubspeciesAuthority, FieldFamily, Description, ValidCode, ReferenceID) -SELECT sp.SpeciesID, - sp.GenusID, - sp.Mnemonic, - sp.SpeciesName, - MIN(subs.SubSpeciesName), - sp.IDLevel, - sp.Authority, - MIN(subs.Authority), - sp.FieldFamily, - LEFT(sp.Description, 65535), - NULL, - sp.ReferenceID -FROM stable_panama.species sp - LEFT JOIN stable_panama.subspecies subs ON sp.SpeciesID = subs.SpeciesID - LEFT JOIN stable_panama.reference ref ON sp.ReferenceID = ref.ReferenceID -GROUP BY sp.SpeciesID, sp.GenusID, sp.Mnemonic, sp.IDLevel, sp.Authority, sp.FieldFamily, sp.Description, sp.ReferenceID -ON DUPLICATE KEY UPDATE GenusID = VALUES(GenusID), - SpeciesCode = VALUES(SpeciesCode), - SpeciesName = VALUES(SpeciesName), - SubspeciesName = IF(VALUES(SubspeciesName) != '', VALUES(SubspeciesName), - species.SubspeciesName), - IDLevel = VALUES(IDLevel), - SpeciesAuthority = IF(VALUES(SpeciesAuthority) != '', VALUES(SpeciesAuthority), - species.SpeciesAuthority), - SubspeciesAuthority = IF(VALUES(SubspeciesAuthority) != '', VALUES(SubspeciesAuthority), - species.SubspeciesAuthority), - FieldFamily = VALUES(FieldFamily), - Description = IF(VALUES(Description) != '', VALUES(Description), species.Description), - ValidCode = VALUES(ValidCode), - ReferenceID = VALUES(ReferenceID); - --- First, update the census table for any invalid StartDate entries -UPDATE stable_panama.census -SET StartDate = NULL -WHERE CAST(StartDate AS CHAR(10)) = '0000-00-00'; - --- Insert into census with ON DUPLICATE KEY UPDATE, using UNION between census and censusbackup -INSERT INTO census (CensusID, PlotID, StartDate, EndDate, Description, PlotCensusNumber) -SELECT - c.CensusID, - c.PlotID, - COALESCE(MIN(d.ExactDate), c.StartDate) AS StartDate, - COALESCE(MAX(d.ExactDate), c.EndDate) AS EndDate, - LEFT(c.Description, 65535) AS Description, - c.PlotCensusNumber -FROM ( - -- Combine census and censusbackup using UNION - SELECT - CensusID, PlotID, StartDate, EndDate, Description, PlotCensusNumber - FROM stable_panama.census - UNION - SELECT - CensusID, PlotID, StartDate, EndDate, Description, PlotCensusNumber - FROM stable_panama.censusbackup -) c -LEFT JOIN stable_panama.dbh d ON c.CensusID = d.CensusID -GROUP BY - c.CensusID, - c.PlotID, - c.StartDate, - c.EndDate, - c.Description, - c.PlotCensusNumber -ON DUPLICATE KEY UPDATE - PlotID = VALUES(PlotID), - StartDate = VALUES(StartDate), - EndDate = VALUES(EndDate), - Description = IF(VALUES(Description) != '', VALUES(Description), census.Description), - PlotCensusNumber = VALUES(PlotCensusNumber); - --- Insert into roles table -INSERT INTO roles (RoleID, RoleName, RoleDescription) -SELECT RoleID, Description, NULL -FROM stable_panama.rolereference -ON DUPLICATE KEY UPDATE RoleName = VALUES(RoleName), - RoleDescription = VALUES(RoleDescription); - --- Insert into personnel, ensuring each personnel is re-added for each CensusID with new PersonnelID --- Step 1: Create a temporary table to hold the intermediate results -CREATE TEMPORARY TABLE tmp_personnel -SELECT - c.CensusID, - p.FirstName, - p.LastName, - pr.RoleID -FROM - stable_panama.personnel p -CROSS JOIN - stable_panama.census c -JOIN - stable_panama.personnelrole pr ON p.PersonnelID = pr.PersonnelID; - --- Step 2: Insert into personnel from the temporary table, handling duplicates -INSERT INTO personnel (CensusID, FirstName, LastName, RoleID) -SELECT - CensusID, - FirstName, - LastName, - RoleID -FROM - tmp_personnel -ON DUPLICATE KEY UPDATE - RoleID = VALUES(RoleID); - --- Step 3: Drop the temporary table -DROP TEMPORARY TABLE tmp_personnel; - --- Insert into quadrats with ON DUPLICATE KEY UPDATE -INSERT INTO quadrats (QuadratID, PlotID, CensusID, QuadratName, StartX, StartY, DimensionX, DimensionY, DimensionUnits, - Area, AreaUnits, QuadratShape, CoordinateUnits) -SELECT q.QuadratID, - q.PlotID, - cq.CensusID, - LEFT(q.QuadratName, 65535), - MIN(co.PX), - MIN(co.PY), - s.QDimX, - s.QDimY, - IF(s.QUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), s.QUOM, 'm'), - q.Area, - IF(s.QUOM IN ('km2', 'hm2', 'dam2', 'm2', 'dm2', 'cm2', 'mm2'), s.QUOM, 'm2'), - IF(q.IsStandardShape = 'Y', 'standard', 'not standard'), - IF(s.GUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), s.GUOM, 'm') -FROM stable_panama.quadrat q - LEFT JOIN stable_panama.censusquadrat cq ON q.QuadratID = cq.QuadratID - LEFT JOIN stable_panama.Coordinates co ON q.QuadratID = co.QuadratID - LEFT JOIN stable_panama.Site s ON q.PlotID = s.PlotID -GROUP BY q.QuadratID, q.PlotID, cq.CensusID, q.QuadratName, s.QDimX, s.QDimY, s.QUOM, q.Area, q.IsStandardShape, s.GUOM -ON DUPLICATE KEY UPDATE PlotID = VALUES(PlotID), - CensusID = VALUES(CensusID), - QuadratName = IF(VALUES(QuadratName) != '', VALUES(QuadratName), quadrats.QuadratName), - StartX = VALUES(StartX), - StartY = VALUES(StartY), - DimensionX = VALUES(DimensionX), - DimensionY = VALUES(DimensionY), - DimensionUnits = VALUES(DimensionUnits), - Area = VALUES(Area), - AreaUnits = VALUES(AreaUnits), - QuadratShape = VALUES(QuadratShape), - CoordinateUnits = VALUES(CoordinateUnits); - --- Insert into trees with ON DUPLICATE KEY UPDATE -INSERT INTO trees (TreeID, TreeTag, SpeciesID) -SELECT t.TreeID, t.Tag, t.SpeciesID -FROM stable_panama.tree t -ON DUPLICATE KEY UPDATE TreeTag = IF(VALUES(TreeTag) != '', VALUES(TreeTag), trees.TreeTag), - SpeciesID = VALUES(SpeciesID); - --- Insert into stems with ON DUPLICATE KEY UPDATE -INSERT INTO stems (StemID, TreeID, QuadratID, StemNumber, StemTag, LocalX, LocalY, CoordinateUnits, Moved, - StemDescription) -SELECT s.StemID, - s.TreeID, - s.QuadratID, - s.StemNumber, - s.StemTag, - MIN(s.QX), - MIN(s.QY), - IF(si.QUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), si.QUOM, 'm') AS CoordinateUnits, - IF(s.Moved = 'Y', 1, 0) AS Moved, - LEFT(s.StemDescription, 65535) -FROM stable_panama.stem s - LEFT JOIN stable_panama.quadrat q ON q.QuadratID = s.QuadratID - LEFT JOIN stable_panama.Site si ON q.PlotID = si.PlotID -GROUP BY s.StemID, s.TreeID, s.QuadratID, s.StemNumber, s.StemTag, s.Moved, s.StemDescription, si.QUOM -ON DUPLICATE KEY UPDATE TreeID = VALUES(TreeID), - QuadratID = VALUES(QuadratID), - StemNumber = VALUES(StemNumber), - StemTag = IF(VALUES(StemTag) != '', VALUES(StemTag), stems.StemTag), - LocalX = VALUES(LocalX), - LocalY = VALUES(LocalY), - CoordinateUnits = VALUES(CoordinateUnits), - Moved = VALUES(Moved), - StemDescription = IF(VALUES(StemDescription) != '', VALUES(StemDescription), - stems.StemDescription); - --- Insert into coremeasurements with ON DUPLICATE KEY UPDATE -INSERT INTO coremeasurements (CoreMeasurementID, CensusID, StemID, IsValidated, MeasurementDate, MeasuredDBH, DBHUnit, - MeasuredHOM, HOMUnit, Description, UserDefinedFields) -SELECT dbh.DBHID, - dbh.CensusID, - dbh.StemID, - NULL, - dbh.ExactDate, - CAST(dbh.DBH AS DECIMAL(10, 6)), - 'cm', - CAST(dbh.HOM AS DECIMAL(10, 6)), - 'm', - LEFT(dbh.Comments, 65535), - NULL -FROM stable_panama.dbh dbh -ON DUPLICATE KEY UPDATE StemID = VALUES(StemID), - IsValidated = VALUES(IsValidated), - MeasurementDate = VALUES(MeasurementDate), - MeasuredDBH = VALUES(MeasuredDBH), - DBHUnit = VALUES(DBHUnit), - MeasuredHOM = VALUES(MeasuredHOM), - HOMUnit = VALUES(HOMUnit), - Description = IF(VALUES(Description) != '', VALUES(Description), - coremeasurements.Description), - UserDefinedFields = VALUES(UserDefinedFields); - --- Insert into quadratpersonnel with ON DUPLICATE KEY UPDATE -INSERT INTO quadratpersonnel (QuadratPersonnelID, QuadratID, PersonnelID, CensusID) -SELECT dc.DataCollectionID, dc.QuadratID, pr.PersonnelID, dc.CensusID -FROM stable_panama.datacollection dc - JOIN stable_panama.personnelrole pr ON dc.PersonnelRoleID = pr.PersonnelRoleID -ON DUPLICATE KEY UPDATE QuadratID = VALUES(QuadratID), - PersonnelID = VALUES(PersonnelID), - CensusID = VALUES(CensusID); - --- Insert into attributes with ON DUPLICATE KEY UPDATE -INSERT INTO attributes (Code, Description, Status) -SELECT ta.TSMCode, - LEFT(ta.Description, 65535), - IF(ta.Status IN ('alive', 'alive-not measured', 'dead', 'stem dead', 'broken below', 'omitted', 'missing'), - ta.Status, NULL) -FROM stable_panama.tsmattributes ta -GROUP BY ta.TSMCode, ta.Description, ta.Status -ON DUPLICATE KEY UPDATE Description = IF(VALUES(Description) != '', VALUES(Description), attributes.Description), - Status = VALUES(Status); - --- Insert into cmattributes with ON DUPLICATE KEY UPDATE -INSERT INTO cmattributes (CMAID, CoreMeasurementID, Code) -SELECT dbha.DBHAttID, dbha.DBHID, ta.TSMCode -FROM stable_panama.dbhattributes dbha - JOIN stable_panama.tsmattributes ta ON dbha.TSMID = ta.TSMID -ON DUPLICATE KEY UPDATE CoreMeasurementID = VALUES(CoreMeasurementID), - Code = VALUES(Code); - --- Insert into specimens with ON DUPLICATE KEY UPDATE -INSERT INTO specimens (SpecimenID, StemID, PersonnelID, SpecimenNumber, SpeciesID, Herbarium, Voucher, CollectionDate, - DeterminedBy, Description) -SELECT sp.SpecimenID, - st.StemID, - pr.PersonnelID, - sp.SpecimenNumber, - sp.SpeciesID, - sp.Herbarium, - sp.Voucher, - sp.CollectionDate, - sp.DeterminedBy, - LEFT(sp.Description, 65535) -FROM stable_panama.specimen sp - LEFT JOIN stable_panama.stem st ON st.TreeID = sp.TreeID - LEFT JOIN stable_panama.personnel pr ON sp.Collector = CONCAT(pr.FirstName, ' ', pr.LastName) -ON DUPLICATE KEY UPDATE StemID = VALUES(StemID), - PersonnelID = VALUES(PersonnelID), - SpecimenNumber = VALUES(SpecimenNumber), - SpeciesID = VALUES(SpeciesID), - Herbarium = VALUES(Herbarium), - Voucher = VALUES(Voucher), - CollectionDate = VALUES(CollectionDate), - DeterminedBy = IF(VALUES(DeterminedBy) != '', VALUES(DeterminedBy), specimens.DeterminedBy), - Description = IF(VALUES(Description) != '', VALUES(Description), specimens.Description); - -SET foreign_key_checks = 1; diff --git a/frontend/sqlscripting/resetautoincrements.sql b/frontend/sqlscripting/resetautoincrements.sql deleted file mode 100644 index 30bd5980..00000000 --- a/frontend/sqlscripting/resetautoincrements.sql +++ /dev/null @@ -1,165 +0,0 @@ --- Reset auto_increment for plots -SET @max_value = (SELECT IFNULL(MAX(PlotID), 0) - FROM plots); -SET @query = CONCAT('ALTER TABLE plots AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - - --- Reset auto_increment for census -SET @max_value = (SELECT IFNULL(MAX(CensusID), 0) - FROM census); -SET @query = CONCAT('ALTER TABLE census AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - - --- Reset auto_increment for quadrats -SET @max_value = (SELECT IFNULL(MAX(QuadratID), 0) - FROM quadrats); -SET @query = CONCAT('ALTER TABLE quadrats AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - --- Reset auto_increment for reference -SET @max_value = (SELECT IFNULL(MAX(ReferenceID), 0) - FROM reference); -SET @query = CONCAT('ALTER TABLE reference AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - --- Reset auto_increment for family -SET @max_value = (SELECT IFNULL(MAX(FamilyID), 0) - FROM family); -SET @query = CONCAT('ALTER TABLE family AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - --- Reset auto_increment for genus -SET @max_value = (SELECT IFNULL(MAX(GenusID), 0) - FROM genus); -SET @query = CONCAT('ALTER TABLE genus AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - --- Reset auto_increment for roles -SET @max_value = (SELECT IFNULL(MAX(RoleID), 0) - FROM roles); -SET @query = CONCAT('ALTER TABLE roles AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - --- Reset auto_increment for personnel -SET @max_value = (SELECT IFNULL(MAX(PersonnelID), 0) - FROM personnel); -SET @query = CONCAT('ALTER TABLE personnel AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - --- Reset auto_increment for quadratpersonnel -SET @max_value = (SELECT IFNULL(MAX(QuadratPersonnelID), 0) - FROM quadratpersonnel); -SET @query = CONCAT('ALTER TABLE quadratpersonnel AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - --- Reset auto_increment for species -SET @max_value = (SELECT IFNULL(MAX(SpeciesID), 0) - FROM species); -SET @query = CONCAT('ALTER TABLE species AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - --- Reset auto_increment for specieslimits -SET @max_value = (SELECT IFNULL(MAX(SpeciesLimitID), 0) - FROM specieslimits); -SET @query = CONCAT('ALTER TABLE specieslimits AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - --- Reset auto_increment for subquadrats -SET @max_value = (SELECT IFNULL(MAX(SubquadratID), 0) - FROM subquadrats); -SET @query = CONCAT('ALTER TABLE subquadrats AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - --- Reset auto_increment for trees -SET @max_value = (SELECT IFNULL(MAX(TreeID), 0) - FROM trees); -SET @query = CONCAT('ALTER TABLE trees AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - --- Reset auto_increment for stems -SET @max_value = (SELECT IFNULL(MAX(StemID), 0) - FROM stems); -SET @query = CONCAT('ALTER TABLE stems AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - --- Reset auto_increment for coremeasurements -SET @max_value = (SELECT IFNULL(MAX(CoreMeasurementID), 0) - FROM coremeasurements); -SET @query = CONCAT('ALTER TABLE coremeasurements AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - --- Reset auto_increment for cmattributes -SET @max_value = (SELECT IFNULL(MAX(CMAID), 0) - FROM cmattributes); -SET @query = CONCAT('ALTER TABLE cmattributes AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - --- Reset auto_increment for cmverrors -SET @max_value = (SELECT IFNULL(MAX(CMVErrorID), 0) - FROM cmverrors); -SET @query = CONCAT('ALTER TABLE cmverrors AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - --- Reset auto_increment for specimens -SET @max_value = (SELECT IFNULL(MAX(SpecimenID), 0) - FROM specimens); -SET @query = CONCAT('ALTER TABLE specimens AUTO_INCREMENT = ', @max_value + 1); -PREPARE stmt FROM @query; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - --- Reset auto_increment for unifiedchangelog -# SET @max_value = (SELECT IFNULL(MAX(ChangeID), 0) FROM unifiedchangelog); -# SET @query = CONCAT('ALTER TABLE unifiedchangelog AUTO_INCREMENT = ', @max_value + 1); -# PREPARE stmt FROM @query; -# EXECUTE stmt; -# DEALLOCATE PREPARE stmt; - -truncate table unifiedchangelog; - --- Reset auto_increment for validationchangelog -# SET @max_value = (SELECT IFNULL(MAX(ValidationRunID), 0) FROM validationchangelog); -# SET @new_auto_increment = @max_value + 1; -# ALTER TABLE validationchangelog AUTO_INCREMENT = @new_auto_increment; -truncate table validationchangelog; - --- Reset auto_increment for viewfulltable -CALL RefreshViewFullTable(); - -CALL RefreshMeasurementsSummary(); \ No newline at end of file diff --git a/frontend/sqlscripting/resetschema.sql b/frontend/sqlscripting/resetschema.sql deleted file mode 100644 index 98d679b1..00000000 --- a/frontend/sqlscripting/resetschema.sql +++ /dev/null @@ -1,24 +0,0 @@ -set foreign_key_checks = 0; -truncate attributes; -truncate census; -truncate cmattributes; -truncate cmverrors; -truncate coremeasurements; -truncate family; -truncate genus; -truncate personnel; -# truncate plots; -truncate quadratpersonnel; -truncate quadrats; -truncate reference; -truncate roles; -truncate species; -truncate specieslimits; -truncate specimens; -truncate stems; -truncate subquadrats; -truncate unifiedchangelog; -truncate validationchangelog; -truncate measurementssummary; -truncate viewfulltable; -set foreign_key_checks = 1; \ No newline at end of file diff --git a/frontend/sqlscripting/resettestingschema.sql b/frontend/sqlscripting/resettestingschema.sql deleted file mode 100644 index e968d797..00000000 --- a/frontend/sqlscripting/resettestingschema.sql +++ /dev/null @@ -1,2798 +0,0 @@ -use -forestgeo_testing; - --- need to make sure you change the source schema from stable_sinharaja as needed! - -set -foreign_key_checks = 0; -truncate attributes; -truncate census; -truncate cmattributes; -truncate cmverrors; -truncate coremeasurements; -truncate family; -truncate genus; -truncate personnel; -truncate plots; -truncate quadratpersonnel; -truncate quadrats; -truncate reference; -truncate roles; -truncate species; -truncate specieslimits; -truncate specimens; -truncate stems; -truncate subquadrats; -truncate unifiedchangelog; -truncate validationchangelog; -set -foreign_key_checks = 1; - -SET -foreign_key_checks = 0; - --- stable_sinharaja: old ctfsweb schema --- forestgeo_scbi: new schema. --- make sure you replace this for each new schema you pull/push from/to. - -# -attributes -DROP TRIGGER IF EXISTS after_insert_attributes; -DROP TRIGGER IF EXISTS after_update_attributes; -DROP TRIGGER IF EXISTS after_delete_attributes; - -# -census -DROP TRIGGER IF EXISTS after_insert_census; -DROP TRIGGER IF EXISTS after_update_census; -DROP TRIGGER IF EXISTS after_delete_census; - -# -cmattributes -DROP TRIGGER IF EXISTS after_insert_cmattributes; -DROP TRIGGER IF EXISTS after_update_cmattributes; -DROP TRIGGER IF EXISTS after_delete_cmattributes; - -# -cmverrors -DROP TRIGGER IF EXISTS after_insert_cmverrors; -DROP TRIGGER IF EXISTS after_update_cmverrors; -DROP TRIGGER IF EXISTS after_delete_cmverrors; - -# -coremeasurements -DROP TRIGGER IF EXISTS after_insert_coremeasurements; -DROP TRIGGER IF EXISTS after_update_coremeasurements; -DROP TRIGGER IF EXISTS after_delete_coremeasurements; - -# -family -DROP TRIGGER IF EXISTS after_insert_family; -DROP TRIGGER IF EXISTS after_update_family; -DROP TRIGGER IF EXISTS after_delete_family; - -# -genus -DROP TRIGGER IF EXISTS after_insert_genus; -DROP TRIGGER IF EXISTS after_update_genus; -DROP TRIGGER IF EXISTS after_delete_genus; - -# -personnel -DROP TRIGGER IF EXISTS after_insert_personnel; -DROP TRIGGER IF EXISTS after_update_personnel; -DROP TRIGGER IF EXISTS after_delete_personnel; - -# -plots -DROP TRIGGER IF EXISTS after_insert_plots; -DROP TRIGGER IF EXISTS after_update_plots; -DROP TRIGGER IF EXISTS after_delete_plots; - -# -quadratpersonnel -DROP TRIGGER IF EXISTS after_insert_quadratpersonnel; -DROP TRIGGER IF EXISTS after_update_quadratpersonnel; -DROP TRIGGER IF EXISTS after_delete_quadratpersonnel; - -# -quadrats -DROP TRIGGER IF EXISTS after_insert_quadrats; -DROP TRIGGER IF EXISTS after_update_quadrats; -DROP TRIGGER IF EXISTS after_delete_quadrats; - -# -reference -DROP TRIGGER IF EXISTS after_insert_reference; -DROP TRIGGER IF EXISTS after_update_reference; -DROP TRIGGER IF EXISTS after_delete_reference; - -# -roles -DROP TRIGGER IF EXISTS after_insert_roles; -DROP TRIGGER IF EXISTS after_update_roles; -DROP TRIGGER IF EXISTS after_delete_roles; - -# -species -DROP TRIGGER IF EXISTS after_insert_species; -DROP TRIGGER IF EXISTS after_update_species; -DROP TRIGGER IF EXISTS after_delete_species; - -# -specieslimits -DROP TRIGGER IF EXISTS after_insert_specieslimits; -DROP TRIGGER IF EXISTS after_update_specieslimits; -DROP TRIGGER IF EXISTS after_delete_specieslimits; - -# -specimens -DROP TRIGGER IF EXISTS after_insert_specimens; -DROP TRIGGER IF EXISTS after_update_specimens; -DROP TRIGGER IF EXISTS after_delete_specimens; - -# -stems -DROP TRIGGER IF EXISTS after_insert_stems; -DROP TRIGGER IF EXISTS after_update_stems; -DROP TRIGGER IF EXISTS after_delete_stems; - -# -subquadrats -DROP TRIGGER IF EXISTS after_insert_subquadrats; -DROP TRIGGER IF EXISTS after_update_subquadrats; -DROP TRIGGER IF EXISTS after_delete_subquadrats; - -# -trees -DROP TRIGGER IF EXISTS after_insert_trees; -DROP TRIGGER IF EXISTS after_update_trees; -DROP TRIGGER IF EXISTS after_delete_trees; - -# -validationchangelog -DROP TRIGGER IF EXISTS after_insert_validationchangelog; -DROP TRIGGER IF EXISTS after_update_validationchangelog; -DROP TRIGGER IF EXISTS after_delete_validationchangelog; - --- Insert into plots with ON DUPLICATE KEY UPDATE -INSERT INTO plots (PlotID, PlotName, LocationName, CountryName, DimensionX, DimensionY, DimensionUnits, Area, AreaUnits, - GlobalX, GlobalY, GlobalZ, CoordinateUnits, PlotShape, PlotDescription) -SELECT s.PlotID, LEFT (s.PlotName, 65535), LEFT (s.LocationName, 65535), c.CountryName, s.QDimX, s.QDimY, IF(s.PUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), s.PUOM, 'm'), s.Area, 'm2', co.GX, co.GY, co.GZ, IF(s.GUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), s.GUOM, 'm'), s.ShapeOfSite, LEFT (s.DescriptionOfSite, 65535) -FROM stable_sinharaja.Site s - LEFT JOIN stable_sinharaja.Country c -ON s.CountryID = c.CountryID - LEFT JOIN stable_sinharaja.Coordinates co ON s.PlotID = co.PlotID -GROUP BY s.PlotID, s.PlotName, s.LocationName, c.CountryName, s.QDimX, s.QDimY, s.PUOM, s.Area, s.GUOM, co.GX, co.GY, - co.GZ, s.ShapeOfSite, s.DescriptionOfSite -ON DUPLICATE KEY -UPDATE PlotName = IF(VALUES (PlotName) != '', VALUES (PlotName), plots.PlotName), - LocationName = IF(VALUES (LocationName) != '', VALUES (LocationName), plots.LocationName), - CountryName = IF(VALUES (CountryName) != '', VALUES (CountryName), plots.CountryName), - DimensionX = -VALUES (DimensionX), DimensionY = -VALUES (DimensionY), DimensionUnits = -VALUES (DimensionUnits), Area = -VALUES (Area), AreaUnits = -VALUES (AreaUnits), GlobalX = -VALUES (GlobalX), GlobalY = -VALUES (GlobalY), GlobalZ = -VALUES (GlobalZ), CoordinateUnits = -VALUES (CoordinateUnits), PlotShape = -VALUES (PlotShape), PlotDescription = IF(VALUES (PlotDescription) != '', VALUES (PlotDescription), plots.PlotDescription); - --- Insert into reference with ON DUPLICATE KEY UPDATE and handling '0000-00-00' dates -INSERT INTO reference (ReferenceID, PublicationTitle, FullReference, DateOfPublication, Citation) -SELECT r.ReferenceID, - r.PublicationTitle, - r.FullReference, - IF(CAST(r.DateofPublication AS CHAR) = '0000-00-00', NULL, r.DateofPublication) AS DateOfPublication, - NULL -FROM stable_sinharaja.reference r ON DUPLICATE KEY -UPDATE PublicationTitle = IF(VALUES (PublicationTitle) != '', VALUES (PublicationTitle), - reference.PublicationTitle), - FullReference = IF(VALUES (FullReference) != '', VALUES (FullReference), - reference.FullReference), - reference.DateOfPublication = -VALUES (DateOfPublication); - --- Insert into family with ON DUPLICATE KEY UPDATE -INSERT INTO family (FamilyID, Family, ReferenceID) -SELECT f.FamilyID, f.Family, f.ReferenceID -FROM stable_sinharaja.family f ON DUPLICATE KEY -UPDATE Family = IF(VALUES (Family) != '', VALUES (Family), family.Family), - ReferenceID = -VALUES (ReferenceID); - --- Insert into genus with ON DUPLICATE KEY UPDATE -INSERT INTO genus (GenusID, FamilyID, Genus, ReferenceID, GenusAuthority) -SELECT g.GenusID, g.FamilyID, g.Genus, g.ReferenceID, g.Authority -FROM stable_sinharaja.genus g ON DUPLICATE KEY -UPDATE FamilyID = -VALUES (FamilyID), Genus = IF(VALUES (Genus) != '', VALUES (Genus), genus.Genus), ReferenceID = -VALUES (ReferenceID), GenusAuthority = IF(VALUES (GenusAuthority) != '', VALUES (GenusAuthority), genus.GenusAuthority); - --- Insert into species with ON DUPLICATE KEY UPDATE -INSERT INTO species (SpeciesID, GenusID, SpeciesCode, SpeciesName, SubspeciesName, IDLevel, SpeciesAuthority, - SubspeciesAuthority, FieldFamily, Description, ValidCode, ReferenceID) -SELECT sp.SpeciesID, - sp.GenusID, - sp.Mnemonic, - sp.SpeciesName, - MIN(subs.SubSpeciesName), - sp.IDLevel, - sp.Authority, - MIN(subs.Authority), - sp.FieldFamily, LEFT (sp.Description, 65535), NULL, sp.ReferenceID -FROM stable_sinharaja.species sp - LEFT JOIN stable_sinharaja.subspecies subs -ON sp.SpeciesID = subs.SpeciesID - LEFT JOIN stable_sinharaja.reference ref ON sp.ReferenceID = ref.ReferenceID -GROUP BY sp.SpeciesID, sp.GenusID, sp.Mnemonic, sp.IDLevel, sp.Authority, sp.FieldFamily, sp.Description, sp.ReferenceID -ON DUPLICATE KEY -UPDATE GenusID = -VALUES (GenusID), SpeciesCode = -VALUES (SpeciesCode), SpeciesName = -VALUES (SpeciesName), SubspeciesName = IF(VALUES (SubspeciesName) != '', VALUES (SubspeciesName), species.SubspeciesName), IDLevel = -VALUES (IDLevel), SpeciesAuthority = IF(VALUES (SpeciesAuthority) != '', VALUES (SpeciesAuthority), species.SpeciesAuthority), SubspeciesAuthority = IF(VALUES (SubspeciesAuthority) != '', VALUES (SubspeciesAuthority), species.SubspeciesAuthority), FieldFamily = -VALUES (FieldFamily), Description = IF(VALUES (Description) != '', VALUES (Description), species.Description), ValidCode = -VALUES (ValidCode), ReferenceID = -VALUES (ReferenceID); - -UPDATE stable_sinharaja.census -SET StartDate = NULL -WHERE CAST(StartDate AS CHAR(10)) = '0000-00-00'; - --- Insert into census with ON DUPLICATE KEY UPDATE -INSERT INTO census (CensusID, PlotID, StartDate, EndDate, Description, PlotCensusNumber) -SELECT c.CensusID, c.PlotID, c.StartDate, c.EndDate, LEFT (c.Description, 65535), c.PlotCensusNumber -FROM stable_sinharaja.census c -ON DUPLICATE KEY -UPDATE PlotID = -VALUES (PlotID), StartDate = -VALUES (StartDate), EndDate = -VALUES (EndDate), Description = IF(VALUES (Description) != '', VALUES (Description), census.Description), PlotCensusNumber = -VALUES (PlotCensusNumber); - --- Insert into roles table -INSERT INTO roles (RoleID, RoleName, RoleDescription) -SELECT RoleID, Description, NULL -FROM stable_sinharaja.rolereference ON DUPLICATE KEY -UPDATE RoleName = -VALUES (RoleName), RoleDescription = -VALUES (RoleDescription); - --- Insert into personnel, ensuring each personnel is re-added for each CensusID with new PersonnelID -INSERT INTO personnel (CensusID, FirstName, LastName, RoleID) -SELECT c.CensusID, - p.FirstName, - p.LastName, - pr.RoleID -FROM stable_sinharaja.personnel p - CROSS JOIN - stable_sinharaja.census c - JOIN - stable_sinharaja.personnelrole pr ON p.PersonnelID = pr.PersonnelID; - --- Insert into quadrats with ON DUPLICATE KEY UPDATE -INSERT INTO quadrats (QuadratID, PlotID, CensusID, QuadratName, StartX, StartY, DimensionX, DimensionY, DimensionUnits, - Area, AreaUnits, QuadratShape, CoordinateUnits) -SELECT q.QuadratID, - q.PlotID, - cq.CensusID, LEFT (q.QuadratName, 65535), MIN (co.PX), MIN (co.PY), s.QDimX, s.QDimY, IF(s.QUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), s.QUOM, 'm'), q.Area, IF(s.QUOM IN ('km2', 'hm2', 'dam2', 'm2', 'dm2', 'cm2', 'mm2'), s.QUOM, 'm2'), IF(q.IsStandardShape = 'Y', 'standard', 'not standard'), IF(s.GUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), s.GUOM, 'm') -FROM stable_sinharaja.quadrat q - LEFT JOIN stable_sinharaja.censusquadrat cq -ON q.QuadratID = cq.QuadratID - LEFT JOIN stable_sinharaja.Coordinates co ON q.QuadratID = co.QuadratID - LEFT JOIN stable_sinharaja.Site s ON q.PlotID = s.PlotID -GROUP BY q.QuadratID, q.PlotID, cq.CensusID, q.QuadratName, s.QDimX, s.QDimY, s.QUOM, q.Area, q.IsStandardShape, s.GUOM -ON DUPLICATE KEY -UPDATE PlotID = -VALUES (PlotID), CensusID = -VALUES (CensusID), QuadratName = IF(VALUES (QuadratName) != '', VALUES (QuadratName), quadrats.QuadratName), StartX = -VALUES (StartX), StartY = -VALUES (StartY), DimensionX = -VALUES (DimensionX), DimensionY = -VALUES (DimensionY), DimensionUnits = -VALUES (DimensionUnits), Area = -VALUES (Area), AreaUnits = -VALUES (AreaUnits), QuadratShape = -VALUES (QuadratShape), CoordinateUnits = -VALUES (CoordinateUnits); - --- Insert into trees with ON DUPLICATE KEY UPDATE -INSERT INTO trees (TreeID, TreeTag, SpeciesID) -SELECT t.TreeID, t.Tag, t.SpeciesID -FROM stable_sinharaja.tree t ON DUPLICATE KEY -UPDATE TreeTag = IF(VALUES (TreeTag) != '', VALUES (TreeTag), trees.TreeTag), - SpeciesID = -VALUES (SpeciesID); - --- Insert into stems with ON DUPLICATE KEY UPDATE -INSERT INTO stems (StemID, TreeID, QuadratID, StemNumber, StemTag, LocalX, LocalY, CoordinateUnits, Moved, - StemDescription) -SELECT s.StemID, - s.TreeID, - s.QuadratID, - s.StemNumber, - s.StemTag, - MIN(s.QX), - MIN(s.QY), - IF(si.QUOM IN ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm'), si.QUOM, 'm') AS CoordinateUnits, - IF(s.Moved = 'Y', 1, 0) AS Moved, LEFT (s.StemDescription, 65535) -FROM stable_sinharaja.stem s - LEFT JOIN stable_sinharaja.quadrat q -ON q.QuadratID = s.QuadratID - LEFT JOIN stable_sinharaja.Site si ON q.PlotID = si.PlotID -GROUP BY s.StemID, s.TreeID, s.QuadratID, s.StemNumber, s.StemTag, s.Moved, s.StemDescription, si.QUOM -ON DUPLICATE KEY -UPDATE TreeID = -VALUES (TreeID), QuadratID = -VALUES (QuadratID), StemNumber = -VALUES (StemNumber), StemTag = IF(VALUES (StemTag) != '', VALUES (StemTag), stems.StemTag), LocalX = -VALUES (LocalX), LocalY = -VALUES (LocalY), CoordinateUnits = -VALUES (CoordinateUnits), Moved = -VALUES (Moved), StemDescription = IF(VALUES (StemDescription) != '', VALUES (StemDescription), stems.StemDescription); - --- Insert into coremeasurements with ON DUPLICATE KEY UPDATE -INSERT INTO coremeasurements (CoreMeasurementID, StemID, IsValidated, MeasurementDate, MeasuredDBH, DBHUnit, - MeasuredHOM, HOMUnit, Description, UserDefinedFields) -SELECT dbh.DBHID, - dbh.StemID, - NULL, - dbh.ExactDate, - dbh.DBH, - 'cm', - dbh.HOM, - 'm', LEFT (dbh.Comments, 65535), NULL -FROM stable_sinharaja.dbh dbh -ON DUPLICATE KEY -UPDATE StemID = -VALUES (StemID), IsValidated = -VALUES (IsValidated), MeasurementDate = -VALUES (MeasurementDate), MeasuredDBH = -VALUES (MeasuredDBH), DBHUnit = -VALUES (DBHUnit), MeasuredHOM = -VALUES (MeasuredHOM), HOMUnit = -VALUES (HOMUnit), Description = IF(VALUES (Description) != '', VALUES (Description), coremeasurements.Description), UserDefinedFields = -VALUES (UserDefinedFields); - --- Insert into quadratpersonnel with ON DUPLICATE KEY UPDATE -INSERT INTO quadratpersonnel (QuadratPersonnelID, QuadratID, PersonnelID, CensusID) -SELECT dc.DataCollectionID, dc.QuadratID, pr.PersonnelID, dc.CensusID -FROM stable_sinharaja.datacollection dc - JOIN stable_sinharaja.personnelrole pr ON dc.PersonnelRoleID = pr.PersonnelRoleID ON DUPLICATE KEY -UPDATE QuadratID = -VALUES (QuadratID), PersonnelID = -VALUES (PersonnelID), CensusID = -VALUES (CensusID); - --- Insert into attributes with ON DUPLICATE KEY UPDATE -INSERT INTO attributes (Code, Description, Status) -SELECT ta.TSMCode, LEFT (ta.Description, 65535), IF(ta.Status IN ('alive', 'alive-not measured', 'dead', 'stem dead', 'broken below', 'omitted', 'missing'), ta.Status, NULL) -FROM stable_sinharaja.tsmattributes ta -GROUP BY ta.TSMCode, ta.Description, ta.Status -ON DUPLICATE KEY -UPDATE Description = IF(VALUES (Description) != '', VALUES (Description), attributes.Description), - Status = -VALUES (Status); - --- Insert into cmattributes with ON DUPLICATE KEY UPDATE -INSERT INTO cmattributes (CMAID, CoreMeasurementID, Code) -SELECT dbha.DBHAttID, dbha.DBHID, ta.TSMCode -FROM stable_sinharaja.dbhattributes dbha - JOIN stable_sinharaja.tsmattributes ta ON dbha.TSMID = ta.TSMID ON DUPLICATE KEY -UPDATE CoreMeasurementID = -VALUES (CoreMeasurementID), Code = -VALUES (Code); - --- Insert into specimens with ON DUPLICATE KEY UPDATE -INSERT INTO specimens (SpecimenID, StemID, PersonnelID, SpecimenNumber, SpeciesID, Herbarium, Voucher, CollectionDate, - DeterminedBy, Description) -SELECT sp.SpecimenID, - st.StemID, - pr.PersonnelID, - sp.SpecimenNumber, - sp.SpeciesID, - sp.Herbarium, - sp.Voucher, - sp.CollectionDate, - sp.DeterminedBy, LEFT (sp.Description, 65535) -FROM stable_sinharaja.specimen sp - LEFT JOIN stable_sinharaja.stem st -ON st.TreeID = sp.TreeID - LEFT JOIN stable_sinharaja.personnel pr ON sp.Collector = CONCAT(pr.FirstName, ' ', pr.LastName) - ON DUPLICATE KEY -UPDATE StemID = -VALUES (StemID), PersonnelID = -VALUES (PersonnelID), SpecimenNumber = -VALUES (SpecimenNumber), SpeciesID = -VALUES (SpeciesID), Herbarium = -VALUES (Herbarium), Voucher = -VALUES (Voucher), CollectionDate = -VALUES (CollectionDate), DeterminedBy = IF(VALUES (DeterminedBy) != '', VALUES (DeterminedBy), specimens.DeterminedBy), Description = IF(VALUES (Description) != '', VALUES (Description), specimens.Description); - -SET -foreign_key_checks = 1; - -# -attributes triggers - -DELIMITER // - -CREATE TRIGGER after_insert_attributes - AFTER INSERT - ON attributes - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - - -- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'Code', NEW.Code, - 'Description', NEW.Description, - 'Status', NEW.Status - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('attributes', - NEW.Code, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_attributes - AFTER UPDATE - ON attributes - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the new row - SET old_json = JSON_OBJECT( - 'Code', OLD.Code, - 'Description', OLD.Description, - 'Status', OLD.Status - ); - - -- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'Code', NEW.Code, - 'Description', NEW.Description, - 'Status', NEW.Status - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('attributes', - NEW.Code, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_attributes - AFTER DELETE - ON attributes - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the new row - SET old_json = JSON_OBJECT( - 'Code', OLD.Code, - 'Description', OLD.Description, - 'Status', OLD.Status - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('attributes', - OLD.Code, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -plots triggers -DELIMITER // - -CREATE TRIGGER after_insert_plots - AFTER INSERT - ON plots - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'PlotID', NEW.PlotID, - 'PlotName', NEW.PlotName, - 'LocationName', NEW.LocationName, - 'CountryName', NEW.CountryName, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'Area', NEW.Area, - 'AreaUnits', NEW.AreaUnits, - 'GlobalX', NEW.GlobalX, - 'GlobalY', NEW.GlobalY, - 'GlobalZ', NEW.GlobalZ, - 'CoordinateUnits', NEW.CoordinateUnits, - 'PlotShape', NEW.PlotShape, - 'PlotDescription', NEW.PlotDescription - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('plots', - NEW.PlotID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_plots - AFTER UPDATE - ON plots - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'PlotID', OLD.PlotID, - 'PlotName', OLD.PlotName, - 'LocationName', OLD.LocationName, - 'CountryName', OLD.CountryName, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'Area', OLD.Area, - 'AreaUnits', OLD.AreaUnits, - 'GlobalX', OLD.GlobalX, - 'GlobalY', OLD.GlobalY, - 'GlobalZ', OLD.GlobalZ, - 'CoordinateUnits', OLD.CoordinateUnits, - 'PlotShape', OLD.PlotShape, - 'PlotDescription', OLD.PlotDescription - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'PlotID', NEW.PlotID, - 'PlotName', NEW.PlotName, - 'LocationName', NEW.LocationName, - 'CountryName', NEW.CountryName, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'Area', NEW.Area, - 'AreaUnits', NEW.AreaUnits, - 'GlobalX', NEW.GlobalX, - 'GlobalY', NEW.GlobalY, - 'GlobalZ', NEW.GlobalZ, - 'CoordinateUnits', NEW.CoordinateUnits, - 'PlotShape', NEW.PlotShape, - 'PlotDescription', NEW.PlotDescription - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('plots', - NEW.PlotID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_plots - AFTER DELETE - ON plots - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'PlotID', OLD.PlotID, - 'PlotName', OLD.PlotName, - 'LocationName', OLD.LocationName, - 'CountryName', OLD.CountryName, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'Area', OLD.Area, - 'AreaUnits', OLD.AreaUnits, - 'GlobalX', OLD.GlobalX, - 'GlobalY', OLD.GlobalY, - 'GlobalZ', OLD.GlobalZ, - 'CoordinateUnits', OLD.CoordinateUnits, - 'PlotShape', OLD.PlotShape, - 'PlotDescription', OLD.PlotDescription - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('plots', - OLD.PlotID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -census triggers - -DELIMITER // - -CREATE TRIGGER after_insert_census - AFTER INSERT - ON census - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'CensusID', NEW.CensusID, - 'PlotID', NEW.PlotID, - 'StartDate', NEW.StartDate, - 'EndDate', NEW.EndDate, - 'Description', NEW.Description, - 'PlotCensusNumber', NEW.PlotCensusNumber - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('census', - NEW.CensusID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_census - AFTER UPDATE - ON census - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'CensusID', OLD.CensusID, - 'PlotID', OLD.PlotID, - 'StartDate', OLD.StartDate, - 'EndDate', OLD.EndDate, - 'Description', OLD.Description, - 'PlotCensusNumber', OLD.PlotCensusNumber - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'CensusID', NEW.CensusID, - 'PlotID', NEW.PlotID, - 'StartDate', NEW.StartDate, - 'EndDate', NEW.EndDate, - 'Description', NEW.Description, - 'PlotCensusNumber', NEW.PlotCensusNumber - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('census', - NEW.CensusID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_census - AFTER DELETE - ON census - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'CensusID', OLD.CensusID, - 'PlotID', OLD.PlotID, - 'StartDate', OLD.StartDate, - 'EndDate', OLD.EndDate, - 'Description', OLD.Description, - 'PlotCensusNumber', OLD.PlotCensusNumber - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('census', - OLD.CensusID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -quadrats triggers - -DELIMITER // - -CREATE TRIGGER after_insert_quadrats - AFTER INSERT - ON quadrats - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'QuadratID', NEW.QuadratID, - 'PlotID', NEW.PlotID, - 'CensusID', NEW.CensusID, - 'QuadratName', NEW.QuadratName, - 'StartX', NEW.StartX, - 'StartY', NEW.StartY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'Area', NEW.Area, - 'AreaUnits', NEW.AreaUnits, - 'QuadratShape', NEW.QuadratShape - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadrats', - NEW.QuadratID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_quadrats - AFTER UPDATE - ON quadrats - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'QuadratID', OLD.QuadratID, - 'PlotID', OLD.PlotID, - 'CensusID', OLD.CensusID, - 'QuadratName', OLD.QuadratName, - 'StartX', OLD.StartX, - 'StartY', OLD.StartY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'Area', OLD.Area, - 'AreaUnits', OLD.AreaUnits, - 'QuadratShape', OLD.QuadratShape - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'QuadratID', NEW.QuadratID, - 'PlotID', NEW.PlotID, - 'CensusID', NEW.CensusID, - 'QuadratName', NEW.QuadratName, - 'StartX', NEW.StartX, - 'StartY', NEW.StartY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'Area', NEW.Area, - 'AreaUnits', NEW.AreaUnits, - 'QuadratShape', NEW.QuadratShape - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadrats', - NEW.QuadratID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_quadrats - AFTER DELETE - ON quadrats - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'QuadratID', OLD.QuadratID, - 'PlotID', OLD.PlotID, - 'CensusID', OLD.CensusID, - 'QuadratName', OLD.QuadratName, - 'StartX', OLD.StartX, - 'StartY', OLD.StartY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'Area', OLD.Area, - 'AreaUnits', OLD.AreaUnits, - 'QuadratShape', OLD.QuadratShape - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadrats', - OLD.QuadratID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -reference triggers - -DELIMITER // - -CREATE TRIGGER after_insert_reference - AFTER INSERT - ON reference - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'ReferenceID', NEW.ReferenceID, - 'PublicationTitle', NEW.PublicationTitle, - 'FullReference', NEW.FullReference, - 'DateOfPublication', NEW.DateOfPublication, - 'Citation', NEW.Citation - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('reference', - NEW.ReferenceID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_reference - AFTER UPDATE - ON reference - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'ReferenceID', OLD.ReferenceID, - 'PublicationTitle', OLD.PublicationTitle, - 'FullReference', OLD.FullReference, - 'DateOfPublication', OLD.DateOfPublication, - 'Citation', OLD.Citation - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'ReferenceID', NEW.ReferenceID, - 'PublicationTitle', NEW.PublicationTitle, - 'FullReference', NEW.FullReference, - 'DateOfPublication', NEW.DateOfPublication, - 'Citation', NEW.Citation - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('reference', - NEW.ReferenceID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_reference - AFTER DELETE - ON reference - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'ReferenceID', OLD.ReferenceID, - 'PublicationTitle', OLD.PublicationTitle, - 'FullReference', OLD.FullReference, - 'DateOfPublication', OLD.DateOfPublication, - 'Citation', OLD.Citation - ); - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('reference', - OLD.ReferenceID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -family triggers - -DELIMITER // - -CREATE TRIGGER after_insert_family - AFTER INSERT - ON family - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'FamilyID', NEW.FamilyID, - 'Family', NEW.Family, - 'ReferenceID', NEW.ReferenceID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('family', - NEW.FamilyID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_family - AFTER UPDATE - ON family - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'FamilyID', OLD.FamilyID, - 'Family', OLD.Family, - 'ReferenceID', OLD.ReferenceID - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'FamilyID', NEW.FamilyID, - 'Family', NEW.Family, - 'ReferenceID', NEW.ReferenceID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('family', - NEW.FamilyID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_family - AFTER DELETE - ON family - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'FamilyID', OLD.FamilyID, - 'Family', OLD.Family, - 'ReferenceID', OLD.ReferenceID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('family', - OLD.FamilyID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -genus triggers - -DELIMITER // - -CREATE TRIGGER after_insert_genus - AFTER INSERT - ON genus - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'GenusID', NEW.GenusID, - 'FamilyID', NEW.FamilyID, - 'Genus', NEW.Genus, - 'ReferenceID', NEW.ReferenceID, - 'GenusAuthority', NEW.GenusAuthority - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('genus', - NEW.GenusID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_genus - AFTER UPDATE - ON genus - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'GenusID', OLD.GenusID, - 'FamilyID', OLD.FamilyID, - 'Genus', OLD.Genus, - 'ReferenceID', OLD.ReferenceID, - 'GenusAuthority', OLD.GenusAuthority - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'GenusID', NEW.GenusID, - 'FamilyID', NEW.FamilyID, - 'Genus', NEW.Genus, - 'ReferenceID', NEW.ReferenceID, - 'GenusAuthority', NEW.GenusAuthority - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('genus', - NEW.GenusID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_genus - AFTER DELETE - ON genus - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'GenusID', OLD.GenusID, - 'FamilyID', OLD.FamilyID, - 'Genus', OLD.Genus, - 'ReferenceID', OLD.ReferenceID, - 'GenusAuthority', OLD.GenusAuthority - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('genus', - OLD.GenusID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -roles triggers - -DELIMITER // - -CREATE TRIGGER after_insert_roles - AFTER INSERT - ON roles - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'RoleID', NEW.RoleID, - 'RoleName', NEW.RoleName, - 'RoleDescription', NEW.RoleDescription - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('roles', - NEW.RoleID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_roles - AFTER UPDATE - ON roles - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'RoleID', OLD.RoleID, - 'RoleName', OLD.RoleName, - 'RoleDescription', OLD.RoleDescription - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'RoleID', NEW.RoleID, - 'RoleName', NEW.RoleName, - 'RoleDescription', NEW.RoleDescription - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('roles', - NEW.RoleID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_roles - AFTER DELETE - ON roles - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'RoleID', OLD.RoleID, - 'RoleName', OLD.RoleName, - 'RoleDescription', OLD.RoleDescription - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('roles', - OLD.RoleID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -personnel triggers - -DELIMITER // - -CREATE TRIGGER after_insert_personnel - AFTER INSERT - ON personnel - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'PersonnelID', NEW.PersonnelID, - 'CensusID', NEW.CensusID, - 'FirstName', NEW.FirstName, - 'LastName', NEW.LastName, - 'RoleID', NEW.RoleID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('personnel', - NEW.PersonnelID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_personnel - AFTER UPDATE - ON personnel - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'PersonnelID', OLD.PersonnelID, - 'CensusID', OLD.CensusID, - 'FirstName', OLD.FirstName, - 'LastName', OLD.LastName, - 'RoleID', OLD.RoleID - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'PersonnelID', NEW.PersonnelID, - 'CensusID', NEW.CensusID, - 'FirstName', NEW.FirstName, - 'LastName', NEW.LastName, - 'RoleID', NEW.RoleID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('personnel', - NEW.PersonnelID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_personnel - AFTER DELETE - ON personnel - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'PersonnelID', OLD.PersonnelID, - 'CensusID', OLD.CensusID, - 'FirstName', OLD.FirstName, - 'LastName', OLD.LastName, - 'RoleID', OLD.RoleID - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('personnel', - OLD.PersonnelID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -quadratpersonnel triggers - -DELIMITER // - -CREATE TRIGGER after_insert_quadratpersonnel - AFTER INSERT - ON quadratpersonnel - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'QuadratPersonnelID', NEW.QuadratPersonnelID, - 'QuadratID', NEW.QuadratID, - 'PersonnelID', NEW.PersonnelID, - 'CensusID', NEW.CensusID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadratpersonnel', - NEW.QuadratPersonnelID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_quadratpersonnel - AFTER UPDATE - ON quadratpersonnel - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'QuadratPersonnelID', OLD.QuadratPersonnelID, - 'QuadratID', OLD.QuadratID, - 'PersonnelID', OLD.PersonnelID, - 'CensusID', OLD.CensusID - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'QuadratPersonnelID', NEW.QuadratPersonnelID, - 'QuadratID', NEW.QuadratID, - 'PersonnelID', NEW.PersonnelID, - 'CensusID', NEW.CensusID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadratpersonnel', - NEW.QuadratPersonnelID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_quadratpersonnel - AFTER DELETE - ON quadratpersonnel - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'QuadratPersonnelID', OLD.QuadratPersonnelID, - 'QuadratID', OLD.QuadratID, - 'PersonnelID', OLD.PersonnelID, - 'CensusID', OLD.CensusID - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadratpersonnel', - OLD.QuadratPersonnelID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -species triggers - -DELIMITER // - -CREATE TRIGGER after_insert_species - AFTER INSERT - ON species - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'SpeciesID', NEW.SpeciesID, - 'GenusID', NEW.GenusID, - 'CensusID', NEW.CensusID, - 'SpeciesCode', NEW.SpeciesCode, - 'SpeciesName', NEW.SpeciesName, - 'SubspeciesName', NEW.SubspeciesName, - 'IDLevel', NEW.IDLevel, - 'SpeciesAuthority', NEW.SpeciesAuthority, - 'SubspeciesAuthority', NEW.SubspeciesAuthority, - 'FieldFamily', NEW.FieldFamily, - 'Description', NEW.Description, - 'ValidCode', NEW.ValidCode, - 'ReferenceID', NEW.ReferenceID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('species', - NEW.SpeciesID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_species - AFTER UPDATE - ON species - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'SpeciesID', OLD.SpeciesID, - 'GenusID', OLD.GenusID, - 'CensusID', OLD.CensusID, - 'SpeciesCode', OLD.SpeciesCode, - 'SpeciesName', OLD.SpeciesName, - 'SubspeciesName', OLD.SubspeciesName, - 'IDLevel', OLD.IDLevel, - 'SpeciesAuthority', OLD.SpeciesAuthority, - 'SubspeciesAuthority', OLD.SubspeciesAuthority, - 'FieldFamily', OLD.FieldFamily, - 'Description', OLD.Description, - 'ValidCode', OLD.ValidCode, - 'ReferenceID', OLD.ReferenceID - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'SpeciesID', NEW.SpeciesID, - 'GenusID', NEW.GenusID, - 'CensusID', NEW.CensusID, - 'SpeciesCode', NEW.SpeciesCode, - 'SpeciesName', NEW.SpeciesName, - 'SubspeciesName', NEW.SubspeciesName, - 'IDLevel', NEW.IDLevel, - 'SpeciesAuthority', NEW.SpeciesAuthority, - 'SubspeciesAuthority', NEW.SubspeciesAuthority, - 'FieldFamily', NEW.FieldFamily, - 'Description', NEW.Description, - 'ValidCode', NEW.ValidCode, - 'ReferenceID', NEW.ReferenceID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('species', - NEW.SpeciesID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_species - AFTER DELETE - ON species - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'SpeciesID', OLD.SpeciesID, - 'GenusID', OLD.GenusID, - 'CensusID', OLD.CensusID, - 'SpeciesCode', OLD.SpeciesCode, - 'SpeciesName', OLD.SpeciesName, - 'SubspeciesName', OLD.SubspeciesName, - 'IDLevel', OLD.IDLevel, - 'SpeciesAuthority', OLD.SpeciesAuthority, - 'SubspeciesAuthority', OLD.SubspeciesAuthority, - 'FieldFamily', OLD.FieldFamily, - 'Description', OLD.Description, - 'ValidCode', OLD.ValidCode, - 'ReferenceID', OLD.ReferenceID - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('species', - OLD.SpeciesID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -specieslimits triggers - -DELIMITER // - -CREATE TRIGGER after_insert_specieslimits - AFTER INSERT - ON specieslimits - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'SpeciesLimitID', NEW.SpeciesLimitID, - 'SpeciesCode', NEW.SpeciesCode, - 'LimitType', NEW.LimitType, - 'UpperBound', NEW.UpperBound, - 'LowerBound', NEW.LowerBound, - 'Unit', NEW.Unit - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('specieslimits', - NEW.SpeciesLimitID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_specieslimits - AFTER UPDATE - ON specieslimits - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'SpeciesLimitID', OLD.SpeciesLimitID, - 'SpeciesCode', OLD.SpeciesCode, - 'LimitType', OLD.LimitType, - 'UpperBound', OLD.UpperBound, - 'LowerBound', OLD.LowerBound, - 'Unit', OLD.Unit - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'SpeciesLimitID', NEW.SpeciesLimitID, - 'SpeciesCode', NEW.SpeciesCode, - 'LimitType', NEW.LimitType, - 'UpperBound', NEW.UpperBound, - 'LowerBound', NEW.LowerBound, - 'Unit', NEW.Unit - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('specieslimits', - NEW.SpeciesLimitID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_specieslimits - AFTER DELETE - ON specieslimits - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'SpeciesLimitID', OLD.SpeciesLimitID, - 'SpeciesCode', OLD.SpeciesCode, - 'LimitType', OLD.LimitType, - 'UpperBound', OLD.UpperBound, - 'LowerBound', OLD.LowerBound, - 'Unit', OLD.Unit - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('specieslimits', - OLD.SpeciesLimitID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -subquadrats triggers - -DELIMITER // - -CREATE TRIGGER after_insert_subquadrats - AFTER INSERT - ON subquadrats - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'SubquadratID', NEW.SubquadratID, - 'SubquadratName', NEW.SubquadratName, - 'QuadratID', NEW.QuadratID, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'QX', NEW.QX, - 'QY', NEW.QY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'Ordering', NEW.Ordering - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('subquadrats', - NEW.SubquadratID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_subquadrats - AFTER UPDATE - ON subquadrats - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'SubquadratID', OLD.SubquadratID, - 'SubquadratName', OLD.SubquadratName, - 'QuadratID', OLD.QuadratID, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'QX', OLD.QX, - 'QY', OLD.QY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'Ordering', OLD.Ordering - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'SubquadratID', NEW.SubquadratID, - 'SubquadratName', NEW.SubquadratName, - 'QuadratID', NEW.QuadratID, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'QX', NEW.QX, - 'QY', NEW.QY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'Ordering', NEW.Ordering - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('subquadrats', - NEW.SubquadratID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_subquadrats - AFTER DELETE - ON subquadrats - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'SubquadratID', OLD.SubquadratID, - 'SubquadratName', OLD.SubquadratName, - 'QuadratID', OLD.QuadratID, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'QX', OLD.QX, - 'QY', OLD.QY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'Ordering', OLD.Ordering - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('subquadrats', - OLD.SubquadratID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -trees triggers - -DELIMITER // - -CREATE TRIGGER after_insert_trees - AFTER INSERT - ON trees - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'TreeID', NEW.TreeID, - 'TreeTag', NEW.TreeTag, - 'SpeciesID', NEW.SpeciesID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('trees', - NEW.TreeID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_trees - AFTER UPDATE - ON trees - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'TreeID', OLD.TreeID, - 'TreeTag', OLD.TreeTag, - 'SpeciesID', OLD.SpeciesID - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'TreeID', NEW.TreeID, - 'TreeTag', NEW.TreeTag, - 'SpeciesID', NEW.SpeciesID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('trees', - NEW.TreeID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_trees - AFTER DELETE - ON trees - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'TreeID', OLD.TreeID, - 'TreeTag', OLD.TreeTag, - 'SpeciesID', OLD.SpeciesID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('trees', - OLD.TreeID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -stems triggers - -DELIMITER // - -CREATE TRIGGER after_insert_stems - AFTER INSERT - ON stems - FOR EACH ROW -BEGIN - DECLARE new_json JSON; --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'StemID', NEW.StemID, - 'TreeID', NEW.TreeID, - 'QuadratID', NEW.QuadratID, - 'StemNumber', NEW.StemNumber, - 'StemTag', NEW.StemTag, - 'LocalX', NEW.LocalX, - 'LocalY', NEW.LocalY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'Moved', NEW.Moved, - 'StemDescription', NEW.StemDescription - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('stems', - NEW.StemID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_stems - AFTER UPDATE - ON stems - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'StemID', OLD.StemID, - 'TreeID', OLD.TreeID, - 'QuadratID', OLD.QuadratID, - 'StemNumber', OLD.StemNumber, - 'StemTag', OLD.StemTag, - 'LocalX', OLD.LocalX, - 'LocalY', OLD.LocalY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'Moved', OLD.Moved, - 'StemDescription', OLD.StemDescription - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'StemID', NEW.StemID, - 'TreeID', NEW.TreeID, - 'QuadratID', NEW.QuadratID, - 'StemNumber', NEW.StemNumber, - 'StemTag', NEW.StemTag, - 'LocalX', NEW.LocalX, - 'LocalY', NEW.LocalY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'Moved', NEW.Moved, - 'StemDescription', NEW.StemDescription - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('stems', - NEW.StemID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_stems - AFTER DELETE - ON stems - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'StemID', OLD.StemID, - 'TreeID', OLD.TreeID, - 'QuadratID', OLD.QuadratID, - 'StemNumber', OLD.StemNumber, - 'StemTag', OLD.StemTag, - 'LocalX', OLD.LocalX, - 'LocalY', OLD.LocalY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'Moved', OLD.Moved, - 'StemDescription', OLD.StemDescription - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('stems', - OLD.StemID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -coremeasurements triggers - -DELIMITER // - -CREATE TRIGGER after_insert_coremeasurements - AFTER INSERT - ON coremeasurements - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'StemID', NEW.StemID, - 'IsValidated', NEW.IsValidated, - 'MeasurementDate', NEW.MeasurementDate, - 'MeasuredDBH', NEW.MeasuredDBH, - 'DBHUnit', NEW.DBHUnit, - 'MeasuredHOM', NEW.MeasuredHOM, - 'HOMUnit', NEW.HOMUnit, - 'Description', NEW.Description, - 'UserDefinedFields', NEW.UserDefinedFields - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('coremeasurements', - NEW.CoreMeasurementID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_coremeasurements - AFTER UPDATE - ON coremeasurements - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'StemID', OLD.StemID, - 'IsValidated', OLD.IsValidated, - 'MeasurementDate', OLD.MeasurementDate, - 'MeasuredDBH', OLD.MeasuredDBH, - 'DBHUnit', OLD.DBHUnit, - 'MeasuredHOM', OLD.MeasuredHOM, - 'HOMUnit', OLD.HOMUnit, - 'Description', OLD.Description, - 'UserDefinedFields', OLD.UserDefinedFields - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'StemID', NEW.StemID, - 'IsValidated', NEW.IsValidated, - 'MeasurementDate', NEW.MeasurementDate, - 'MeasuredDBH', NEW.MeasuredDBH, - 'DBHUnit', NEW.DBHUnit, - 'MeasuredHOM', NEW.MeasuredHOM, - 'HOMUnit', NEW.HOMUnit, - 'Description', NEW.Description, - 'UserDefinedFields', NEW.UserDefinedFields - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('coremeasurements', - NEW.CoreMeasurementID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_coremeasurements - AFTER DELETE - ON coremeasurements - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'StemID', OLD.StemID, - 'IsValidated', OLD.IsValidated, - 'MeasurementDate', OLD.MeasurementDate, - 'MeasuredDBH', OLD.MeasuredDBH, - 'DBHUnit', OLD.DBHUnit, - 'MeasuredHOM', OLD.MeasuredHOM, - 'HOMUnit', OLD.HOMUnit, - 'Description', OLD.Description, - 'UserDefinedFields', OLD.UserDefinedFields - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('coremeasurements', - OLD.CoreMeasurementID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -cmattributes triggers - -DELIMITER // - -CREATE TRIGGER after_insert_cmattributes - AFTER INSERT - ON cmattributes - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'CMAID', NEW.CMAID, - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'Code', NEW.Code - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmattributes', - NEW.CMAID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_cmattributes - AFTER UPDATE - ON cmattributes - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'CMAID', OLD.CMAID, - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'Code', OLD.Code - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'CMAID', NEW.CMAID, - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'Code', NEW.Code - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmattributes', - NEW.CMAID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_cmattributes - AFTER DELETE - ON cmattributes - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'CMAID', OLD.CMAID, - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'Code', OLD.Code - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmattributes', - OLD.CMAID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -cmverrors triggers - -DELIMITER // - -CREATE TRIGGER after_insert_cmverrors - AFTER INSERT - ON cmverrors - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'CMVErrorID', NEW.CMVErrorID, - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'ValidationErrorID', NEW.ValidationErrorID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmverrors', - NEW.CMVErrorID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_cmverrors - AFTER UPDATE - ON cmverrors - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'CMVErrorID', OLD.CMVErrorID, - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'ValidationErrorID', OLD.ValidationErrorID - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'CMVErrorID', NEW.CMVErrorID, - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'ValidationErrorID', NEW.ValidationErrorID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmverrors', - NEW.CMVErrorID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_cmverrors - AFTER DELETE - ON cmverrors - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'CMVErrorID', OLD.CMVErrorID, - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'ValidationErrorID', OLD.ValidationErrorID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmverrors', - OLD.CMVErrorID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -specimens triggers - -DELIMITER // - -CREATE TRIGGER after_insert_specimens - AFTER INSERT - ON specimens - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'SpecimenID', NEW.SpecimenID, - 'StemID', NEW.StemID, - 'PersonnelID', NEW.PersonnelID, - 'SpecimenNumber', NEW.SpecimenNumber, - 'SpeciesID', NEW.SpeciesID, - 'Herbarium', NEW.Herbarium, - 'Voucher', NEW.Voucher, - 'CollectionDate', NEW.CollectionDate, - 'DeterminedBy', NEW.DeterminedBy, - 'Description', NEW.Description - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('specimens', - NEW.SpecimenID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_specimens - AFTER UPDATE - ON specimens - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'SpecimenID', OLD.SpecimenID, - 'StemID', OLD.StemID, - 'PersonnelID', OLD.PersonnelID, - 'SpecimenNumber', OLD.SpecimenNumber, - 'SpeciesID', OLD.SpeciesID, - 'Herbarium', OLD.Herbarium, - 'Voucher', OLD.Voucher, - 'CollectionDate', OLD.CollectionDate, - 'DeterminedBy', OLD.DeterminedBy, - 'Description', OLD.Description - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'SpecimenID', NEW.SpecimenID, - 'StemID', NEW.StemID, - 'PersonnelID', NEW.PersonnelID, - 'SpecimenNumber', NEW.SpecimenNumber, - 'SpeciesID', NEW.SpeciesID, - 'Herbarium', NEW.Herbarium, - 'Voucher', NEW.Voucher, - 'CollectionDate', NEW.CollectionDate, - 'DeterminedBy', NEW.DeterminedBy, - 'Description', NEW.Description - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('specimens', - NEW.SpecimenID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_specimens - AFTER DELETE - ON specimens - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'SpecimenID', OLD.SpecimenID, - 'StemID', OLD.StemID, - 'PersonnelID', OLD.PersonnelID, - 'SpecimenNumber', OLD.SpecimenNumber, - 'SpeciesID', OLD.SpeciesID, - 'Herbarium', OLD.Herbarium, - 'Voucher', OLD.Voucher, - 'CollectionDate', OLD.CollectionDate, - 'DeterminedBy', OLD.DeterminedBy, - 'Description', OLD.Description - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('specimens', - OLD.SpecimenID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -validationchangelog triggers - -DELIMITER // - -CREATE TRIGGER after_insert_validationchangelog - AFTER INSERT - ON validationchangelog - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'ValidationRunID', NEW.ValidationRunID, - 'ProcedureName', NEW.ProcedureName, - 'RunDateTime', NEW.RunDateTime, - 'TargetRowID', NEW.TargetRowID, - 'ValidationOutcome', NEW.ValidationOutcome, - 'ErrorMessage', NEW.ErrorMessage, - 'ValidationCriteria', NEW.ValidationCriteria, - 'MeasuredValue', NEW.MeasuredValue, - 'ExpectedValueRange', NEW.ExpectedValueRange, - 'AdditionalDetails', NEW.AdditionalDetails - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('validationchangelog', - NEW.ValidationRunID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_validationchangelog - AFTER UPDATE - ON validationchangelog - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'ValidationRunID', OLD.ValidationRunID, - 'ProcedureName', OLD.ProcedureName, - 'RunDateTime', OLD.RunDateTime, - 'TargetRowID', OLD.TargetRowID, - 'ValidationOutcome', OLD.ValidationOutcome, - 'ErrorMessage', OLD.ErrorMessage, - 'ValidationCriteria', OLD.ValidationCriteria, - 'MeasuredValue', OLD.MeasuredValue, - 'ExpectedValueRange', OLD.ExpectedValueRange, - 'AdditionalDetails', OLD.AdditionalDetails - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'ValidationRunID', NEW.ValidationRunID, - 'ProcedureName', NEW.ProcedureName, - 'RunDateTime', NEW.RunDateTime, - 'TargetRowID', NEW.TargetRowID, - 'ValidationOutcome', NEW.ValidationOutcome, - 'ErrorMessage', NEW.ErrorMessage, - 'ValidationCriteria', NEW.ValidationCriteria, - 'MeasuredValue', NEW.MeasuredValue, - 'ExpectedValueRange', NEW.ExpectedValueRange, - 'AdditionalDetails', NEW.AdditionalDetails - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('validationchangelog', - NEW.ValidationRunID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_validationchangelog - AFTER DELETE - ON validationchangelog - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'ValidationRunID', OLD.ValidationRunID, - 'ProcedureName', OLD.ProcedureName, - 'RunDateTime', OLD.RunDateTime, - 'TargetRowID', OLD.TargetRowID, - 'ValidationOutcome', OLD.ValidationOutcome, - 'ErrorMessage', OLD.ErrorMessage, - 'ValidationCriteria', OLD.ValidationCriteria, - 'MeasuredValue', OLD.MeasuredValue, - 'ExpectedValueRange', OLD.ExpectedValueRange, - 'AdditionalDetails', OLD.AdditionalDetails - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('validationchangelog', - OLD.ValidationRunID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; diff --git a/frontend/sqlscripting/storedprocedures.sql b/frontend/sqlscripting/storedprocedures.sql index 98d70ad4..686b8c87 100644 --- a/frontend/sqlscripting/storedprocedures.sql +++ b/frontend/sqlscripting/storedprocedures.sql @@ -1,5 +1,4 @@ drop procedure if exists RefreshMeasurementsSummary; -drop procedure if exists RefreshMeasurementsSummaryDraft; drop procedure if exists RefreshViewFullTable; create @@ -41,51 +40,6 @@ BEGIN LEFT JOIN census c ON cm.CensusID = c.CensusID; END; -create - definer = azureroot@`%` procedure RefreshMeasurementsSummaryDraft() -BEGIN - TRUNCATE TABLE measurementssummary_draft; - INSERT INTO measurementssummary_draft ( - CoreMeasurementID, StemID, TreeID, SpeciesID, QuadratID, PlotID, CensusID, SubmittedBy, SpeciesName, SubspeciesName, SpeciesCode, - TreeTag, StemTag, StemLocalX, StemLocalY, StemUnits, QuadratName, MeasurementDate, MeasuredDBH, DBHUnits, MeasuredHOM, - HOMUnits, IsValidated, Description, Attributes) -SELECT cm.StagingMeasurementID AS CoreMeasurementID, - st.StemID, - t.TreeID, - s.SpeciesID, - q.QuadratID, - q.PlotID, - cm.CensusID, - cm.SubmittedBy, - s.SpeciesName, - s.SubspeciesName, - s.SpeciesCode, - t.TreeTag, - st.StemTag, - st.LocalX AS StemLocalX, - st.LocalY AS StemLocalY, - st.CoordinateUnits AS StemUnits, - q.QuadratName, - cm.MeasurementDate, - cm.MeasuredDBH, - cm.DBHUnit AS DBHUnits, - cm.MeasuredHOM, - cm.HOMUnit AS HOMUnits, - NULL as IsValidated, - cm.Description, - (SELECT GROUP_CONCAT(ca.Code SEPARATOR '; ') - FROM cmattributes ca - WHERE ca.CoreMeasurementID = cm.StagingMeasurementID) AS Attributes -FROM coremeasurements_staging cm - LEFT JOIN stems st ON cm.StemID = st.StemID - LEFT JOIN trees t ON st.TreeID = t.TreeID - LEFT JOIN species s ON t.SpeciesID = s.SpeciesID - LEFT JOIN quadrats q ON st.QuadratID = q.QuadratID - LEFT JOIN census c ON cm.CensusID = c.CensusID; -END; - - - CREATE DEFINER = azureroot@`%` PROCEDURE RefreshViewFullTable() BEGIN -- Truncate the materialized table diff --git a/frontend/sqlscripting/tablestructures.sql b/frontend/sqlscripting/tablestructures.sql index 0d278e5c..f94383a6 100644 --- a/frontend/sqlscripting/tablestructures.sql +++ b/frontend/sqlscripting/tablestructures.sql @@ -35,35 +35,6 @@ create table if not exists measurementssummary Attributes varchar(255) null ); -create table if not exists measurementssummary_draft ( - CoreMeasurementID INT NOT NULL PRIMARY KEY, - StemID INT NULL, - TreeID INT NULL, - SpeciesID INT NULL, - QuadratID INT NULL, - PlotID INT NULL, - CensusID INT NULL, - SubmittedBy INT NOT NULL, - SpeciesName VARCHAR(64) NULL, - SubspeciesName VARCHAR(64) NULL, - SpeciesCode VARCHAR(25) NULL, - TreeTag VARCHAR(10) NULL, - StemTag VARCHAR(10) NULL, - StemLocalX DECIMAL(10, 6) NULL, - StemLocalY DECIMAL(10, 6) NULL, - StemUnits ENUM ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') DEFAULT 'm' NULL, - QuadratName VARCHAR(255) NULL, - MeasurementDate DATE NULL, - MeasuredDBH DECIMAL(10, 6) NULL, - DBHUnits ENUM ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') DEFAULT 'cm' NULL, - MeasuredHOM DECIMAL(10, 6) NULL, - HOMUnits ENUM ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') DEFAULT 'm' NULL, - IsValidated BIT DEFAULT b'0' NULL, - Description VARCHAR(255) NULL, - Attributes VARCHAR(255) NULL -); - - create table if not exists plots ( PlotID int auto_increment @@ -102,7 +73,6 @@ create table if not exists quadrats QuadratID int auto_increment primary key, PlotID int null, - CensusID int null, QuadratName varchar(255) null, StartX decimal(10, 6) null, StartY decimal(10, 6) null, @@ -113,32 +83,33 @@ create table if not exists quadrats Area decimal(10, 6) null, AreaUnits enum ('km2', 'hm2', 'dam2', 'm2', 'dm2', 'cm2', 'mm2') default 'm2' null, QuadratShape varchar(255) null, - constraint unique_quadrat_name_per_census_plot - unique (CensusID, PlotID, QuadratName), + constraint unique_quadrat_name_per_plot + unique (PlotID, QuadratName), constraint Quadrats_Plots_FK - foreign key (PlotID) references plots (PlotID), - constraint quadrats_census_CensusID_fk - foreign key (CensusID) references census (CensusID) + foreign key (PlotID) references plots (PlotID) ); -create index idx_censusid_quadrats - on quadrats (CensusID); - -create index idx_pid_cid_quadrats - on quadrats (PlotID, CensusID); - -create index idx_plotid_quadrats +create index idx_pid_quadrats on quadrats (PlotID); -create index idx_qid_pid_cid_quadrats - on quadrats (QuadratID, PlotID, CensusID); - create index idx_qid_pid_quadrats on quadrats (QuadratID, PlotID); create index idx_quadratid_quadrats on quadrats (QuadratID); +create table if not exists censusquadrat +( + CQID int auto_increment primary key , + CensusID int null, + QuadratID int null, + constraint cq_census_censusid_fk + foreign key (CensusID) references census (CensusID), + constraint cq_quadrats_quadratid_fk + foreign key (QuadratID) references quadrats (QuadratID), + UNIQUE (CensusID, QuadratID) +); + create table if not exists reference ( ReferenceID int auto_increment @@ -335,28 +306,6 @@ create table if not exists coremeasurements foreign key (CensusID) references census (CensusID) ); -CREATE TABLE coremeasurements_staging -( - StagingMeasurementID INT AUTO_INCREMENT PRIMARY KEY, -- Unique ID for each staging record - CensusID INT NULL, - StemID INT NULL, - MeasuredDBH DECIMAL(10, 6) NULL, - DBHUnit ENUM ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') DEFAULT 'cm' NULL, - MeasuredHOM DECIMAL(10, 6) NULL, - HOMUnit ENUM ('km', 'hm', 'dam', 'm', 'dm', 'cm', 'mm') DEFAULT 'm' NULL, - Description VARCHAR(255) NULL, - UserDefinedFields TEXT NULL, -- For additional flexibility to store any extra information - SubmittedBy INT NOT NULL, -- ID of the user who submitted this measurement (User A or User B) - IsReviewed BIT DEFAULT b'0', -- Indicates if the measurement has been reviewed by User C (0 = not reviewed, 1 = reviewed) - IsSelected BIT DEFAULT b'0', -- Indicates if this measurement was selected as the final one by User C (0 = not selected, 1 = selected), - SubmissionDate DATETIME DEFAULT CURRENT_TIMESTAMP, -- Timestamp of when this measurement was submitted - ReviewerID INT NULL, -- ID of the reviewer (User C) who selected this measurement - ReviewedDate DATETIME NULL, -- Timestamp of when the review was completed - - CONSTRAINT FK_CoreMeasurementsStaging_Stems FOREIGN KEY (StemID) REFERENCES stems(StemID), - CONSTRAINT FK_CoreMeasurementsStaging_CensusID FOREIGN KEY (CensusID) REFERENCES census(CensusID) -); - create table if not exists cmattributes ( CMAID int auto_increment diff --git a/frontend/sqlscripting/tempmigratechanges.sql b/frontend/sqlscripting/tempmigratechanges.sql deleted file mode 100644 index 738cdea1..00000000 --- a/frontend/sqlscripting/tempmigratechanges.sql +++ /dev/null @@ -1,6 +0,0 @@ -ALTER TABLE quadrats - ADD CONSTRAINT unique_quadrat_name_per_census_plot - UNIQUE (CensusID, PlotID, QuadratName); -ALTER TABLE personnel - ADD CONSTRAINT unique_full_name_per_census - UNIQUE (CensusID, FirstName, LastName); \ No newline at end of file diff --git a/frontend/sqlscripting/triggers.sql b/frontend/sqlscripting/triggers.sql index adedbe58..b888f78e 100644 --- a/frontend/sqlscripting/triggers.sql +++ b/frontend/sqlscripting/triggers.sql @@ -224,10 +224,14 @@ CREATE TRIGGER after_insert_quadrats FOR EACH ROW BEGIN DECLARE new_json JSON; + DECLARE census_id INT; + + SELECT CensusID INTO census_id + FROM censusquadrat WHERE QuadratID = NEW.QuadratID LIMIT 1; + SET new_json = JSON_OBJECT( 'QuadratID', NEW.QuadratID, 'PlotID', NEW.PlotID, - 'CensusID', NEW.CensusID, 'QuadratName', NEW.QuadratName, 'StartX', NEW.StartX, 'StartY', NEW.StartY, @@ -241,7 +245,7 @@ BEGIN ); INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy, PlotID, CensusID) - VALUES ('quadrats', NEW.QuadratID, 'INSERT', new_json, NOW(), 'User', NEW.PlotID, NEW.CensusID); + VALUES ('quadrats', NEW.QuadratID, 'INSERT', new_json, NOW(), 'User', NEW.PlotID, census_id); END // CREATE TRIGGER after_update_quadrats @@ -251,10 +255,14 @@ CREATE TRIGGER after_update_quadrats BEGIN DECLARE old_json JSON; DECLARE new_json JSON; + DECLARE census_id INT; + + SELECT CensusID INTO census_id + FROM censusquadrat WHERE QuadratID = NEW.QuadratID LIMIT 1; + SET old_json = JSON_OBJECT( 'QuadratID', OLD.QuadratID, 'PlotID', OLD.PlotID, - 'CensusID', OLD.CensusID, 'QuadratName', OLD.QuadratName, 'StartX', OLD.StartX, 'StartY', OLD.StartY, @@ -269,7 +277,6 @@ BEGIN SET new_json = JSON_OBJECT( 'QuadratID', NEW.QuadratID, 'PlotID', NEW.PlotID, - 'CensusID', NEW.CensusID, 'QuadratName', NEW.QuadratName, 'StartX', NEW.StartX, 'StartY', NEW.StartY, @@ -283,7 +290,7 @@ BEGIN ); INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy, PlotID, CensusID) - VALUES ('quadrats', NEW.QuadratID, 'UPDATE', old_json, new_json, NOW(), 'User', NEW.PlotID, NEW.CensusID); + VALUES ('quadrats', NEW.QuadratID, 'UPDATE', old_json, new_json, NOW(), 'User', NEW.PlotID, census_id); END // CREATE TRIGGER after_delete_quadrats @@ -292,10 +299,14 @@ CREATE TRIGGER after_delete_quadrats FOR EACH ROW BEGIN DECLARE old_json JSON; + DECLARE census_id INT; + + SELECT CensusID INTO census_id + FROM censusquadrat WHERE QuadratID = OLD.QuadratID LIMIT 1; + SET old_json = JSON_OBJECT( 'QuadratID', OLD.QuadratID, 'PlotID', OLD.PlotID, - 'CensusID', OLD.CensusID, 'QuadratName', OLD.QuadratName, 'StartX', OLD.StartX, 'StartY', OLD.StartY, @@ -309,7 +320,7 @@ BEGIN ); INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy, PlotID, CensusID) - VALUES ('quadrats', OLD.QuadratID, 'DELETE', old_json, NOW(), 'User', OLD.PlotID, OLD.CensusID); + VALUES ('quadrats', OLD.QuadratID, 'DELETE', old_json, NOW(), 'User', OLD.PlotID, census_id); END // DELIMITER ; @@ -1022,7 +1033,11 @@ BEGIN DECLARE census_id INT; -- Fetch PlotID and CensusID associated with the QuadratID - SELECT PlotID, CensusID INTO plot_id, census_id FROM quadrats WHERE QuadratID = NEW.QuadratID; + SELECT q.PlotID, c.CensusID INTO plot_id, census_id + FROM quadrats q + JOIN censusquadrat cq ON cq.QuadratID = q.QuadratID + JOIN census c ON c.CensusID = cq.CensusID + WHERE q.QuadratID = NEW.QuadratID; SET new_json = JSON_OBJECT( 'StemID', NEW.StemID, @@ -1051,7 +1066,11 @@ BEGIN DECLARE census_id INT; -- Fetch PlotID and CensusID associated with the QuadratID - SELECT PlotID, CensusID INTO plot_id, census_id FROM quadrats WHERE QuadratID = NEW.QuadratID; + SELECT q.PlotID, c.CensusID INTO plot_id, census_id + FROM quadrats q + JOIN censusquadrat cq ON cq.QuadratID = q.QuadratID + JOIN census c ON c.CensusID = cq.CensusID + WHERE q.QuadratID = NEW.QuadratID; SET old_json = JSON_OBJECT( 'StemID', OLD.StemID, @@ -1093,7 +1112,11 @@ BEGIN DECLARE census_id INT; -- Fetch PlotID and CensusID associated with the QuadratID - SELECT PlotID, CensusID INTO plot_id, census_id FROM quadrats WHERE QuadratID = OLD.QuadratID; + SELECT q.PlotID, c.CensusID INTO plot_id, census_id + FROM quadrats q + JOIN censusquadrat cq ON cq.QuadratID = q.QuadratID + JOIN census c ON c.CensusID = cq.CensusID + WHERE q.QuadratID = OLD.QuadratID; SET old_json = JSON_OBJECT( 'StemID', OLD.StemID, diff --git a/frontend/sqlscripting/triggersbackup.sql b/frontend/sqlscripting/triggersbackup.sql deleted file mode 100644 index 300310e4..00000000 --- a/frontend/sqlscripting/triggersbackup.sql +++ /dev/null @@ -1,2376 +0,0 @@ -# -attributes triggers - -DELIMITER // - -CREATE TRIGGER after_insert_attributes - AFTER INSERT - ON attributes - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - - -- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'Code', NEW.Code, - 'Description', NEW.Description, - 'Status', NEW.Status - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('attributes', - NEW.Code, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_attributes - AFTER UPDATE - ON attributes - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the new row - SET old_json = JSON_OBJECT( - 'Code', OLD.Code, - 'Description', OLD.Description, - 'Status', OLD.Status - ); - - -- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'Code', NEW.Code, - 'Description', NEW.Description, - 'Status', NEW.Status - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('attributes', - NEW.Code, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_attributes - AFTER DELETE - ON attributes - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the new row - SET old_json = JSON_OBJECT( - 'Code', OLD.Code, - 'Description', OLD.Description, - 'Status', OLD.Status - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('attributes', - OLD.Code, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -plots triggers -DELIMITER // - -CREATE TRIGGER after_insert_plots - AFTER INSERT - ON plots - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'PlotID', NEW.PlotID, - 'PlotName', NEW.PlotName, - 'LocationName', NEW.LocationName, - 'CountryName', NEW.CountryName, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'Area', NEW.Area, - 'AreaUnits', NEW.AreaUnits, - 'GlobalX', NEW.GlobalX, - 'GlobalY', NEW.GlobalY, - 'GlobalZ', NEW.GlobalZ, - 'CoordinateUnits', NEW.CoordinateUnits, - 'PlotShape', NEW.PlotShape, - 'PlotDescription', NEW.PlotDescription - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('plots', - NEW.PlotID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_plots - AFTER UPDATE - ON plots - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'PlotID', OLD.PlotID, - 'PlotName', OLD.PlotName, - 'LocationName', OLD.LocationName, - 'CountryName', OLD.CountryName, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'Area', OLD.Area, - 'AreaUnits', OLD.AreaUnits, - 'GlobalX', OLD.GlobalX, - 'GlobalY', OLD.GlobalY, - 'GlobalZ', OLD.GlobalZ, - 'CoordinateUnits', OLD.CoordinateUnits, - 'PlotShape', OLD.PlotShape, - 'PlotDescription', OLD.PlotDescription - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'PlotID', NEW.PlotID, - 'PlotName', NEW.PlotName, - 'LocationName', NEW.LocationName, - 'CountryName', NEW.CountryName, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'Area', NEW.Area, - 'AreaUnits', NEW.AreaUnits, - 'GlobalX', NEW.GlobalX, - 'GlobalY', NEW.GlobalY, - 'GlobalZ', NEW.GlobalZ, - 'CoordinateUnits', NEW.CoordinateUnits, - 'PlotShape', NEW.PlotShape, - 'PlotDescription', NEW.PlotDescription - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('plots', - NEW.PlotID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_plots - AFTER DELETE - ON plots - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'PlotID', OLD.PlotID, - 'PlotName', OLD.PlotName, - 'LocationName', OLD.LocationName, - 'CountryName', OLD.CountryName, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'Area', OLD.Area, - 'AreaUnits', OLD.AreaUnits, - 'GlobalX', OLD.GlobalX, - 'GlobalY', OLD.GlobalY, - 'GlobalZ', OLD.GlobalZ, - 'CoordinateUnits', OLD.CoordinateUnits, - 'PlotShape', OLD.PlotShape, - 'PlotDescription', OLD.PlotDescription - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('plots', - OLD.PlotID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -census triggers - -DELIMITER // - -CREATE TRIGGER after_insert_census - AFTER INSERT - ON census - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'CensusID', NEW.CensusID, - 'PlotID', NEW.PlotID, - 'StartDate', NEW.StartDate, - 'EndDate', NEW.EndDate, - 'Description', NEW.Description, - 'PlotCensusNumber', NEW.PlotCensusNumber - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('census', - NEW.CensusID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_census - AFTER UPDATE - ON census - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'CensusID', OLD.CensusID, - 'PlotID', OLD.PlotID, - 'StartDate', OLD.StartDate, - 'EndDate', OLD.EndDate, - 'Description', OLD.Description, - 'PlotCensusNumber', OLD.PlotCensusNumber - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'CensusID', NEW.CensusID, - 'PlotID', NEW.PlotID, - 'StartDate', NEW.StartDate, - 'EndDate', NEW.EndDate, - 'Description', NEW.Description, - 'PlotCensusNumber', NEW.PlotCensusNumber - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('census', - NEW.CensusID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_census - AFTER DELETE - ON census - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'CensusID', OLD.CensusID, - 'PlotID', OLD.PlotID, - 'StartDate', OLD.StartDate, - 'EndDate', OLD.EndDate, - 'Description', OLD.Description, - 'PlotCensusNumber', OLD.PlotCensusNumber - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('census', - OLD.CensusID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -quadrats triggers - -DELIMITER // - -CREATE TRIGGER after_insert_quadrats - AFTER INSERT - ON quadrats - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'QuadratID', NEW.QuadratID, - 'PlotID', NEW.PlotID, - 'CensusID', NEW.CensusID, - 'QuadratName', NEW.QuadratName, - 'StartX', NEW.StartX, - 'StartY', NEW.StartY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'Area', NEW.Area, - 'AreaUnits', NEW.AreaUnits, - 'QuadratShape', NEW.QuadratShape - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadrats', - NEW.QuadratID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_quadrats - AFTER UPDATE - ON quadrats - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'QuadratID', OLD.QuadratID, - 'PlotID', OLD.PlotID, - 'CensusID', OLD.CensusID, - 'QuadratName', OLD.QuadratName, - 'StartX', OLD.StartX, - 'StartY', OLD.StartY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'Area', OLD.Area, - 'AreaUnits', OLD.AreaUnits, - 'QuadratShape', OLD.QuadratShape - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'QuadratID', NEW.QuadratID, - 'PlotID', NEW.PlotID, - 'CensusID', NEW.CensusID, - 'QuadratName', NEW.QuadratName, - 'StartX', NEW.StartX, - 'StartY', NEW.StartY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'Area', NEW.Area, - 'AreaUnits', NEW.AreaUnits, - 'QuadratShape', NEW.QuadratShape - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadrats', - NEW.QuadratID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_quadrats - AFTER DELETE - ON quadrats - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'QuadratID', OLD.QuadratID, - 'PlotID', OLD.PlotID, - 'CensusID', OLD.CensusID, - 'QuadratName', OLD.QuadratName, - 'StartX', OLD.StartX, - 'StartY', OLD.StartY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'Area', OLD.Area, - 'AreaUnits', OLD.AreaUnits, - 'QuadratShape', OLD.QuadratShape - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadrats', - OLD.QuadratID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -reference triggers - -DELIMITER // - -CREATE TRIGGER after_insert_reference - AFTER INSERT - ON reference - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'ReferenceID', NEW.ReferenceID, - 'PublicationTitle', NEW.PublicationTitle, - 'FullReference', NEW.FullReference, - 'DateOfPublication', NEW.DateOfPublication, - 'Citation', NEW.Citation - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('reference', - NEW.ReferenceID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_reference - AFTER UPDATE - ON reference - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'ReferenceID', OLD.ReferenceID, - 'PublicationTitle', OLD.PublicationTitle, - 'FullReference', OLD.FullReference, - 'DateOfPublication', OLD.DateOfPublication, - 'Citation', OLD.Citation - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'ReferenceID', NEW.ReferenceID, - 'PublicationTitle', NEW.PublicationTitle, - 'FullReference', NEW.FullReference, - 'DateOfPublication', NEW.DateOfPublication, - 'Citation', NEW.Citation - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('reference', - NEW.ReferenceID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_reference - AFTER DELETE - ON reference - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'ReferenceID', OLD.ReferenceID, - 'PublicationTitle', OLD.PublicationTitle, - 'FullReference', OLD.FullReference, - 'DateOfPublication', OLD.DateOfPublication, - 'Citation', OLD.Citation - ); - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('reference', - OLD.ReferenceID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -family triggers - -DELIMITER // - -CREATE TRIGGER after_insert_family - AFTER INSERT - ON family - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'FamilyID', NEW.FamilyID, - 'Family', NEW.Family, - 'ReferenceID', NEW.ReferenceID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('family', - NEW.FamilyID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_family - AFTER UPDATE - ON family - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'FamilyID', OLD.FamilyID, - 'Family', OLD.Family, - 'ReferenceID', OLD.ReferenceID - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'FamilyID', NEW.FamilyID, - 'Family', NEW.Family, - 'ReferenceID', NEW.ReferenceID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('family', - NEW.FamilyID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_family - AFTER DELETE - ON family - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'FamilyID', OLD.FamilyID, - 'Family', OLD.Family, - 'ReferenceID', OLD.ReferenceID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('family', - OLD.FamilyID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -genus triggers - -DELIMITER // - -CREATE TRIGGER after_insert_genus - AFTER INSERT - ON genus - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'GenusID', NEW.GenusID, - 'FamilyID', NEW.FamilyID, - 'Genus', NEW.Genus, - 'ReferenceID', NEW.ReferenceID, - 'GenusAuthority', NEW.GenusAuthority - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('genus', - NEW.GenusID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_genus - AFTER UPDATE - ON genus - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'GenusID', OLD.GenusID, - 'FamilyID', OLD.FamilyID, - 'Genus', OLD.Genus, - 'ReferenceID', OLD.ReferenceID, - 'GenusAuthority', OLD.GenusAuthority - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'GenusID', NEW.GenusID, - 'FamilyID', NEW.FamilyID, - 'Genus', NEW.Genus, - 'ReferenceID', NEW.ReferenceID, - 'GenusAuthority', NEW.GenusAuthority - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('genus', - NEW.GenusID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_genus - AFTER DELETE - ON genus - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'GenusID', OLD.GenusID, - 'FamilyID', OLD.FamilyID, - 'Genus', OLD.Genus, - 'ReferenceID', OLD.ReferenceID, - 'GenusAuthority', OLD.GenusAuthority - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('genus', - OLD.GenusID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -roles triggers - -DELIMITER // - -CREATE TRIGGER after_insert_roles - AFTER INSERT - ON roles - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'RoleID', NEW.RoleID, - 'RoleName', NEW.RoleName, - 'RoleDescription', NEW.RoleDescription - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('roles', - NEW.RoleID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_roles - AFTER UPDATE - ON roles - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'RoleID', OLD.RoleID, - 'RoleName', OLD.RoleName, - 'RoleDescription', OLD.RoleDescription - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'RoleID', NEW.RoleID, - 'RoleName', NEW.RoleName, - 'RoleDescription', NEW.RoleDescription - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('roles', - NEW.RoleID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_roles - AFTER DELETE - ON roles - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'RoleID', OLD.RoleID, - 'RoleName', OLD.RoleName, - 'RoleDescription', OLD.RoleDescription - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('roles', - OLD.RoleID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -personnel triggers - -DELIMITER // - -CREATE TRIGGER after_insert_personnel - AFTER INSERT - ON personnel - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'PersonnelID', NEW.PersonnelID, - 'CensusID', NEW.CensusID, - 'FirstName', NEW.FirstName, - 'LastName', NEW.LastName, - 'RoleID', NEW.RoleID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('personnel', - NEW.PersonnelID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_personnel - AFTER UPDATE - ON personnel - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'PersonnelID', OLD.PersonnelID, - 'CensusID', OLD.CensusID, - 'FirstName', OLD.FirstName, - 'LastName', OLD.LastName, - 'RoleID', OLD.RoleID - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'PersonnelID', NEW.PersonnelID, - 'CensusID', NEW.CensusID, - 'FirstName', NEW.FirstName, - 'LastName', NEW.LastName, - 'RoleID', NEW.RoleID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('personnel', - NEW.PersonnelID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_personnel - AFTER DELETE - ON personnel - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'PersonnelID', OLD.PersonnelID, - 'CensusID', OLD.CensusID, - 'FirstName', OLD.FirstName, - 'LastName', OLD.LastName, - 'RoleID', OLD.RoleID - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('personnel', - OLD.PersonnelID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -quadratpersonnel triggers - -DELIMITER // - -CREATE TRIGGER after_insert_quadratpersonnel - AFTER INSERT - ON quadratpersonnel - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'QuadratPersonnelID', NEW.QuadratPersonnelID, - 'QuadratID', NEW.QuadratID, - 'PersonnelID', NEW.PersonnelID, - 'CensusID', NEW.CensusID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadratpersonnel', - NEW.QuadratPersonnelID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_quadratpersonnel - AFTER UPDATE - ON quadratpersonnel - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'QuadratPersonnelID', OLD.QuadratPersonnelID, - 'QuadratID', OLD.QuadratID, - 'PersonnelID', OLD.PersonnelID, - 'CensusID', OLD.CensusID - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'QuadratPersonnelID', NEW.QuadratPersonnelID, - 'QuadratID', NEW.QuadratID, - 'PersonnelID', NEW.PersonnelID, - 'CensusID', NEW.CensusID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadratpersonnel', - NEW.QuadratPersonnelID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_quadratpersonnel - AFTER DELETE - ON quadratpersonnel - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'QuadratPersonnelID', OLD.QuadratPersonnelID, - 'QuadratID', OLD.QuadratID, - 'PersonnelID', OLD.PersonnelID, - 'CensusID', OLD.CensusID - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('quadratpersonnel', - OLD.QuadratPersonnelID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -species triggers - -DELIMITER // - -CREATE TRIGGER after_insert_species - AFTER INSERT - ON species - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'SpeciesID', NEW.SpeciesID, - 'GenusID', NEW.GenusID, - 'SpeciesCode', NEW.SpeciesCode, - 'SpeciesName', NEW.SpeciesName, - 'SubspeciesName', NEW.SubspeciesName, - 'IDLevel', NEW.IDLevel, - 'SpeciesAuthority', NEW.SpeciesAuthority, - 'SubspeciesAuthority', NEW.SubspeciesAuthority, - 'FieldFamily', NEW.FieldFamily, - 'Description', NEW.Description, - 'ValidCode', NEW.ValidCode, - 'ReferenceID', NEW.ReferenceID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('species', - NEW.SpeciesID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_species - AFTER UPDATE - ON species - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'SpeciesID', OLD.SpeciesID, - 'GenusID', OLD.GenusID, - 'SpeciesCode', OLD.SpeciesCode, - 'SpeciesName', OLD.SpeciesName, - 'SubspeciesName', OLD.SubspeciesName, - 'IDLevel', OLD.IDLevel, - 'SpeciesAuthority', OLD.SpeciesAuthority, - 'SubspeciesAuthority', OLD.SubspeciesAuthority, - 'FieldFamily', OLD.FieldFamily, - 'Description', OLD.Description, - 'ValidCode', OLD.ValidCode, - 'ReferenceID', OLD.ReferenceID - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'SpeciesID', NEW.SpeciesID, - 'GenusID', NEW.GenusID, - 'SpeciesCode', NEW.SpeciesCode, - 'SpeciesName', NEW.SpeciesName, - 'SubspeciesName', NEW.SubspeciesName, - 'IDLevel', NEW.IDLevel, - 'SpeciesAuthority', NEW.SpeciesAuthority, - 'SubspeciesAuthority', NEW.SubspeciesAuthority, - 'FieldFamily', NEW.FieldFamily, - 'Description', NEW.Description, - 'ValidCode', NEW.ValidCode, - 'ReferenceID', NEW.ReferenceID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('species', - NEW.SpeciesID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_species - AFTER DELETE - ON species - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'SpeciesID', OLD.SpeciesID, - 'GenusID', OLD.GenusID, - 'SpeciesCode', OLD.SpeciesCode, - 'SpeciesName', OLD.SpeciesName, - 'SubspeciesName', OLD.SubspeciesName, - 'IDLevel', OLD.IDLevel, - 'SpeciesAuthority', OLD.SpeciesAuthority, - 'SubspeciesAuthority', OLD.SubspeciesAuthority, - 'FieldFamily', OLD.FieldFamily, - 'Description', OLD.Description, - 'ValidCode', OLD.ValidCode, - 'ReferenceID', OLD.ReferenceID - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('species', - OLD.SpeciesID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -specieslimits triggers - -DELIMITER // - -CREATE TRIGGER after_insert_specieslimits - AFTER INSERT - ON specieslimits - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'SpeciesLimitID', NEW.SpeciesLimitID, - 'SpeciesCode', NEW.SpeciesCode, - 'LimitType', NEW.LimitType, - 'UpperBound', NEW.UpperBound, - 'LowerBound', NEW.LowerBound, - 'Unit', NEW.Unit - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('specieslimits', - NEW.SpeciesLimitID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_specieslimits - AFTER UPDATE - ON specieslimits - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'SpeciesLimitID', OLD.SpeciesLimitID, - 'SpeciesCode', OLD.SpeciesCode, - 'LimitType', OLD.LimitType, - 'UpperBound', OLD.UpperBound, - 'LowerBound', OLD.LowerBound, - 'Unit', OLD.Unit - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'SpeciesLimitID', NEW.SpeciesLimitID, - 'SpeciesCode', NEW.SpeciesCode, - 'LimitType', NEW.LimitType, - 'UpperBound', NEW.UpperBound, - 'LowerBound', NEW.LowerBound, - 'Unit', NEW.Unit - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('specieslimits', - NEW.SpeciesLimitID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_specieslimits - AFTER DELETE - ON specieslimits - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'SpeciesLimitID', OLD.SpeciesLimitID, - 'SpeciesCode', OLD.SpeciesCode, - 'LimitType', OLD.LimitType, - 'UpperBound', OLD.UpperBound, - 'LowerBound', OLD.LowerBound, - 'Unit', OLD.Unit - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('specieslimits', - OLD.SpeciesLimitID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -subquadrats triggers - -DELIMITER // - -CREATE TRIGGER after_insert_subquadrats - AFTER INSERT - ON subquadrats - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'SubquadratID', NEW.SubquadratID, - 'SubquadratName', NEW.SubquadratName, - 'QuadratID', NEW.QuadratID, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'QX', NEW.QX, - 'QY', NEW.QY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'Ordering', NEW.Ordering - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('subquadrats', - NEW.SubquadratID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_subquadrats - AFTER UPDATE - ON subquadrats - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'SubquadratID', OLD.SubquadratID, - 'SubquadratName', OLD.SubquadratName, - 'QuadratID', OLD.QuadratID, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'QX', OLD.QX, - 'QY', OLD.QY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'Ordering', OLD.Ordering - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'SubquadratID', NEW.SubquadratID, - 'SubquadratName', NEW.SubquadratName, - 'QuadratID', NEW.QuadratID, - 'DimensionX', NEW.DimensionX, - 'DimensionY', NEW.DimensionY, - 'DimensionUnits', NEW.DimensionUnits, - 'QX', NEW.QX, - 'QY', NEW.QY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'Ordering', NEW.Ordering - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('subquadrats', - NEW.SubquadratID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_subquadrats - AFTER DELETE - ON subquadrats - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'SubquadratID', OLD.SubquadratID, - 'SubquadratName', OLD.SubquadratName, - 'QuadratID', OLD.QuadratID, - 'DimensionX', OLD.DimensionX, - 'DimensionY', OLD.DimensionY, - 'DimensionUnits', OLD.DimensionUnits, - 'QX', OLD.QX, - 'QY', OLD.QY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'Ordering', OLD.Ordering - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('subquadrats', - OLD.SubquadratID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -trees triggers - -DELIMITER // - -CREATE TRIGGER after_insert_trees - AFTER INSERT - ON trees - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'TreeID', NEW.TreeID, - 'TreeTag', NEW.TreeTag, - 'SpeciesID', NEW.SpeciesID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('trees', - NEW.TreeID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_trees - AFTER UPDATE - ON trees - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'TreeID', OLD.TreeID, - 'TreeTag', OLD.TreeTag, - 'SpeciesID', OLD.SpeciesID - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'TreeID', NEW.TreeID, - 'TreeTag', NEW.TreeTag, - 'SpeciesID', NEW.SpeciesID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('trees', - NEW.TreeID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_trees - AFTER DELETE - ON trees - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'TreeID', OLD.TreeID, - 'TreeTag', OLD.TreeTag, - 'SpeciesID', OLD.SpeciesID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('trees', - OLD.TreeID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -stems triggers - -DELIMITER // - -CREATE TRIGGER after_insert_stems - AFTER INSERT - ON stems - FOR EACH ROW -BEGIN - DECLARE new_json JSON; --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'StemID', NEW.StemID, - 'TreeID', NEW.TreeID, - 'QuadratID', NEW.QuadratID, - 'StemNumber', NEW.StemNumber, - 'StemTag', NEW.StemTag, - 'LocalX', NEW.LocalX, - 'LocalY', NEW.LocalY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'Moved', NEW.Moved, - 'StemDescription', NEW.StemDescription - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('stems', - NEW.StemID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_stems - AFTER UPDATE - ON stems - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'StemID', OLD.StemID, - 'TreeID', OLD.TreeID, - 'QuadratID', OLD.QuadratID, - 'StemNumber', OLD.StemNumber, - 'StemTag', OLD.StemTag, - 'LocalX', OLD.LocalX, - 'LocalY', OLD.LocalY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'Moved', OLD.Moved, - 'StemDescription', OLD.StemDescription - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'StemID', NEW.StemID, - 'TreeID', NEW.TreeID, - 'QuadratID', NEW.QuadratID, - 'StemNumber', NEW.StemNumber, - 'StemTag', NEW.StemTag, - 'LocalX', NEW.LocalX, - 'LocalY', NEW.LocalY, - 'CoordinateUnits', NEW.CoordinateUnits, - 'Moved', NEW.Moved, - 'StemDescription', NEW.StemDescription - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('stems', - NEW.StemID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_stems - AFTER DELETE - ON stems - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'StemID', OLD.StemID, - 'TreeID', OLD.TreeID, - 'QuadratID', OLD.QuadratID, - 'StemNumber', OLD.StemNumber, - 'StemTag', OLD.StemTag, - 'LocalX', OLD.LocalX, - 'LocalY', OLD.LocalY, - 'CoordinateUnits', OLD.CoordinateUnits, - 'Moved', OLD.Moved, - 'StemDescription', OLD.StemDescription - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('stems', - OLD.StemID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -coremeasurements triggers - -DELIMITER // - -CREATE TRIGGER after_insert_coremeasurements - AFTER INSERT - ON coremeasurements - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'StemID', NEW.StemID, - 'IsValidated', NEW.IsValidated, - 'MeasurementDate', NEW.MeasurementDate, - 'MeasuredDBH', NEW.MeasuredDBH, - 'DBHUnit', NEW.DBHUnit, - 'MeasuredHOM', NEW.MeasuredHOM, - 'HOMUnit', NEW.HOMUnit, - 'Description', NEW.Description, - 'UserDefinedFields', NEW.UserDefinedFields - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('coremeasurements', - NEW.CoreMeasurementID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_coremeasurements - AFTER UPDATE - ON coremeasurements - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'StemID', OLD.StemID, - 'IsValidated', OLD.IsValidated, - 'MeasurementDate', OLD.MeasurementDate, - 'MeasuredDBH', OLD.MeasuredDBH, - 'DBHUnit', OLD.DBHUnit, - 'MeasuredHOM', OLD.MeasuredHOM, - 'HOMUnit', OLD.HOMUnit, - 'Description', OLD.Description, - 'UserDefinedFields', OLD.UserDefinedFields - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'StemID', NEW.StemID, - 'IsValidated', NEW.IsValidated, - 'MeasurementDate', NEW.MeasurementDate, - 'MeasuredDBH', NEW.MeasuredDBH, - 'DBHUnit', NEW.DBHUnit, - 'MeasuredHOM', NEW.MeasuredHOM, - 'HOMUnit', NEW.HOMUnit, - 'Description', NEW.Description, - 'UserDefinedFields', NEW.UserDefinedFields - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('coremeasurements', - NEW.CoreMeasurementID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_coremeasurements - AFTER DELETE - ON coremeasurements - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'StemID', OLD.StemID, - 'IsValidated', OLD.IsValidated, - 'MeasurementDate', OLD.MeasurementDate, - 'MeasuredDBH', OLD.MeasuredDBH, - 'DBHUnit', OLD.DBHUnit, - 'MeasuredHOM', OLD.MeasuredHOM, - 'HOMUnit', OLD.HOMUnit, - 'Description', OLD.Description, - 'UserDefinedFields', OLD.UserDefinedFields - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('coremeasurements', - OLD.CoreMeasurementID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -cmattributes triggers - -DELIMITER // - -CREATE TRIGGER after_insert_cmattributes - AFTER INSERT - ON cmattributes - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'CMAID', NEW.CMAID, - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'Code', NEW.Code - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmattributes', - NEW.CMAID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_cmattributes - AFTER UPDATE - ON cmattributes - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'CMAID', OLD.CMAID, - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'Code', OLD.Code - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'CMAID', NEW.CMAID, - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'Code', NEW.Code - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmattributes', - NEW.CMAID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_cmattributes - AFTER DELETE - ON cmattributes - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'CMAID', OLD.CMAID, - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'Code', OLD.Code - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmattributes', - OLD.CMAID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -cmverrors triggers - -DELIMITER // - -CREATE TRIGGER after_insert_cmverrors - AFTER INSERT - ON cmverrors - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'CMVErrorID', NEW.CMVErrorID, - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'ValidationErrorID', NEW.ValidationErrorID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmverrors', - NEW.CMVErrorID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_cmverrors - AFTER UPDATE - ON cmverrors - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'CMVErrorID', OLD.CMVErrorID, - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'ValidationErrorID', OLD.ValidationErrorID - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'CMVErrorID', NEW.CMVErrorID, - 'CoreMeasurementID', NEW.CoreMeasurementID, - 'ValidationErrorID', NEW.ValidationErrorID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmverrors', - NEW.CMVErrorID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_cmverrors - AFTER DELETE - ON cmverrors - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'CMVErrorID', OLD.CMVErrorID, - 'CoreMeasurementID', OLD.CoreMeasurementID, - 'ValidationErrorID', OLD.ValidationErrorID - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('cmverrors', - OLD.CMVErrorID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -specimens triggers - -DELIMITER // - -CREATE TRIGGER after_insert_specimens - AFTER INSERT - ON specimens - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'SpecimenID', NEW.SpecimenID, - 'StemID', NEW.StemID, - 'PersonnelID', NEW.PersonnelID, - 'SpecimenNumber', NEW.SpecimenNumber, - 'SpeciesID', NEW.SpeciesID, - 'Herbarium', NEW.Herbarium, - 'Voucher', NEW.Voucher, - 'CollectionDate', NEW.CollectionDate, - 'DeterminedBy', NEW.DeterminedBy, - 'Description', NEW.Description - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('specimens', - NEW.SpecimenID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_specimens - AFTER UPDATE - ON specimens - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'SpecimenID', OLD.SpecimenID, - 'StemID', OLD.StemID, - 'PersonnelID', OLD.PersonnelID, - 'SpecimenNumber', OLD.SpecimenNumber, - 'SpeciesID', OLD.SpeciesID, - 'Herbarium', OLD.Herbarium, - 'Voucher', OLD.Voucher, - 'CollectionDate', OLD.CollectionDate, - 'DeterminedBy', OLD.DeterminedBy, - 'Description', OLD.Description - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'SpecimenID', NEW.SpecimenID, - 'StemID', NEW.StemID, - 'PersonnelID', NEW.PersonnelID, - 'SpecimenNumber', NEW.SpecimenNumber, - 'SpeciesID', NEW.SpeciesID, - 'Herbarium', NEW.Herbarium, - 'Voucher', NEW.Voucher, - 'CollectionDate', NEW.CollectionDate, - 'DeterminedBy', NEW.DeterminedBy, - 'Description', NEW.Description - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('specimens', - NEW.SpecimenID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_specimens - AFTER DELETE - ON specimens - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'SpecimenID', OLD.SpecimenID, - 'StemID', OLD.StemID, - 'PersonnelID', OLD.PersonnelID, - 'SpecimenNumber', OLD.SpecimenNumber, - 'SpeciesID', OLD.SpeciesID, - 'Herbarium', OLD.Herbarium, - 'Voucher', OLD.Voucher, - 'CollectionDate', OLD.CollectionDate, - 'DeterminedBy', OLD.DeterminedBy, - 'Description', OLD.Description - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('specimens', - OLD.SpecimenID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -# -validationchangelog triggers - -DELIMITER // - -CREATE TRIGGER after_insert_validationchangelog - AFTER INSERT - ON validationchangelog - FOR EACH ROW -BEGIN - DECLARE new_json JSON; - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'ValidationRunID', NEW.ValidationRunID, - 'ProcedureName', NEW.ProcedureName, - 'RunDateTime', NEW.RunDateTime, - 'TargetRowID', NEW.TargetRowID, - 'ValidationOutcome', NEW.ValidationOutcome, - 'ErrorMessage', NEW.ErrorMessage, - 'ValidationCriteria', NEW.ValidationCriteria, - 'MeasuredValue', NEW.MeasuredValue, - 'ExpectedValueRange', NEW.ExpectedValueRange, - 'AdditionalDetails', NEW.AdditionalDetails - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('validationchangelog', - NEW.ValidationRunID, - 'INSERT', - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_update_validationchangelog - AFTER UPDATE - ON validationchangelog - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - DECLARE new_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'ValidationRunID', OLD.ValidationRunID, - 'ProcedureName', OLD.ProcedureName, - 'RunDateTime', OLD.RunDateTime, - 'TargetRowID', OLD.TargetRowID, - 'ValidationOutcome', OLD.ValidationOutcome, - 'ErrorMessage', OLD.ErrorMessage, - 'ValidationCriteria', OLD.ValidationCriteria, - 'MeasuredValue', OLD.MeasuredValue, - 'ExpectedValueRange', OLD.ExpectedValueRange, - 'AdditionalDetails', OLD.AdditionalDetails - ); - --- Construct the JSON object for the new row - SET new_json = JSON_OBJECT( - 'ValidationRunID', NEW.ValidationRunID, - 'ProcedureName', NEW.ProcedureName, - 'RunDateTime', NEW.RunDateTime, - 'TargetRowID', NEW.TargetRowID, - 'ValidationOutcome', NEW.ValidationOutcome, - 'ErrorMessage', NEW.ErrorMessage, - 'ValidationCriteria', NEW.ValidationCriteria, - 'MeasuredValue', NEW.MeasuredValue, - 'ExpectedValueRange', NEW.ExpectedValueRange, - 'AdditionalDetails', NEW.AdditionalDetails - ); - - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, NewRowState, ChangeTimestamp, ChangedBy) - VALUES ('validationchangelog', - NEW.ValidationRunID, - 'UPDATE', - old_json, - new_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; - -DELIMITER -// - -CREATE TRIGGER after_delete_validationchangelog - AFTER DELETE - ON validationchangelog - FOR EACH ROW -BEGIN - DECLARE old_json JSON; - - -- Construct the JSON object for the old row - SET old_json = JSON_OBJECT( - 'ValidationRunID', OLD.ValidationRunID, - 'ProcedureName', OLD.ProcedureName, - 'RunDateTime', OLD.RunDateTime, - 'TargetRowID', OLD.TargetRowID, - 'ValidationOutcome', OLD.ValidationOutcome, - 'ErrorMessage', OLD.ErrorMessage, - 'ValidationCriteria', OLD.ValidationCriteria, - 'MeasuredValue', OLD.MeasuredValue, - 'ExpectedValueRange', OLD.ExpectedValueRange, - 'AdditionalDetails', OLD.AdditionalDetails - ); - - -- Insert the change log entry into unifiedchangelog - INSERT INTO unifiedchangelog (TableName, RecordID, Operation, OldRowState, ChangeTimestamp, ChangedBy) - VALUES ('validationchangelog', - OLD.ValidationRunID, - 'DELETE', - old_json, - NOW(), - 'User' -- Replace 'User' with the actual username if available - ); -END // - -DELIMITER; diff --git a/frontend/sqlscripting/undorollover.sql b/frontend/sqlscripting/undorollover.sql deleted file mode 100644 index 3826fa18..00000000 --- a/frontend/sqlscripting/undorollover.sql +++ /dev/null @@ -1,42 +0,0 @@ --- Start transaction to ensure atomicity -START TRANSACTION; - --- Identify the most recent CensusID -SET -@latest_census_id = (SELECT MAX(CensusID) FROM census); - --- Identify quadrat IDs associated with the latest CensusID -SET -@quadrat_ids = (SELECT GROUP_CONCAT(QuadratID) FROM quadrats WHERE CensusID = @latest_census_id); - --- Delete rolled-over data in the quadrats table referenced to the newly created CensusID -DELETE -FROM quadrats -WHERE CensusID = @latest_census_id; - --- Delete rolled-over data in the personnel table referenced to the newly created CensusID -DELETE -FROM personnel -WHERE CensusID = @latest_census_id; - --- Delete rolled-over data in the stems table referenced by the quadrat IDs -DELETE -FROM stems -WHERE FIND_IN_SET(QuadratID, @quadrat_ids); - --- Delete the newly created CensusID from the census table -DELETE -FROM census -WHERE CensusID = @latest_census_id; - --- Reset the auto_increment of the census table to ensure the next row added has the same CensusID as the one removed -SET -@new_auto_increment = @latest_census_id; -SET -@sql = CONCAT('ALTER TABLE census AUTO_INCREMENT = ', @new_auto_increment); -PREPARE stmt FROM @sql; -EXECUTE stmt; -DEALLOCATE PREPARE stmt; - --- Commit the transaction -COMMIT; diff --git a/frontend/sqlscripting/updatedviews.sql b/frontend/sqlscripting/updatedviews.sql index a06b9ec1..9dd8fdeb 100644 --- a/frontend/sqlscripting/updatedviews.sql +++ b/frontend/sqlscripting/updatedviews.sql @@ -42,7 +42,8 @@ SELECT s.StemID AS StemID, FROM stems s JOIN trees t ON s.TreeID = t.TreeID JOIN quadrats q ON s.QuadratID = q.QuadratID - JOIN census c ON q.CensusID = c.CensusID + JOIN censusquadrat cq ON q.QuadratID = cq.QuadratID + JOIN census c ON cq.CensusID = c.CensusID JOIN plots p ON c.PlotID = p.PlotID JOIN species sp ON t.SpeciesID = sp.SpeciesID JOIN genus g ON sp.GenusID = g.GenusID