From 69c8436090df5386ff71dfd76f21633080f8c6b6 Mon Sep 17 00:00:00 2001 From: sambokar Date: Tue, 22 Oct 2024 07:50:42 -0400 Subject: [PATCH] updates: incorporating download as form csv format button to retrieve data formatted to match input form standards, instead of default JSON format --- .../[dataType]/[[...slugs]]/route.ts | 130 +++++++++++++++++ .../isolated/isolatedattributesdatagrid.tsx | 2 + .../datagrids/isolateddatagridcommons.tsx | 136 ++++++++++++++++-- .../datagrids/measurementscommons.tsx | 41 +++++- frontend/config/datagridhelpers.ts | 1 + frontend/config/macros/formdetails.ts | 2 +- 6 files changed, 292 insertions(+), 20 deletions(-) create mode 100644 frontend/app/api/formdownload/[dataType]/[[...slugs]]/route.ts diff --git a/frontend/app/api/formdownload/[dataType]/[[...slugs]]/route.ts b/frontend/app/api/formdownload/[dataType]/[[...slugs]]/route.ts new file mode 100644 index 00000000..0f3b83d6 --- /dev/null +++ b/frontend/app/api/formdownload/[dataType]/[[...slugs]]/route.ts @@ -0,0 +1,130 @@ +import { NextRequest, NextResponse } from 'next/server'; +import { PoolConnection } from 'mysql2/promise'; +import { getConn, runQuery } from '@/components/processors/processormacros'; +import MapperFactory from '@/config/datamapper'; +import { AttributesRDS } from '@/config/sqlrdsdefinitions/core'; +import { HTTPResponses } from '@/config/macros'; + +export async function GET(_request: NextRequest, { params }: { params: { dataType: string; slugs?: string[] } }) { + const { dataType, slugs } = params; + if (!dataType || !slugs) throw new Error('data type or slugs not provided'); + const [schema, plotIDParam, censusIDParam] = slugs; + if (!schema) throw new Error('no schema provided'); + + const plotID = plotIDParam ? parseInt(plotIDParam) : undefined; + const censusID = censusIDParam ? parseInt(censusIDParam) : undefined; + + let conn: PoolConnection | null = null; + let query: string = ''; + let results: any[] = []; + let mappedResults: any[] = []; + let formMappedResults: any[] = []; + try { + conn = await getConn(); + switch (dataType) { + case 'attributes': + query = `SELECT * FROM ${schema}.attributes`; + results = await runQuery(conn, query); + mappedResults = MapperFactory.getMapper('attributes').mapData(results); + formMappedResults = mappedResults.map((row: AttributesRDS) => ({ + code: row.code, + description: row.description, + status: row.status + })); + return new NextResponse(JSON.stringify(formMappedResults), { status: HTTPResponses.OK }); + case 'personnel': + query = `SELECT p.FirstName AS FirstName, p.LastName AS LastName, r.RoleName AS RoleName, r.RoleDescription AS RoleDescription + FROM ${schema}.personnel p + LEFT JOIN ${schema}.roles r ON p.RoleID = r.RoleID + LEFT JOIN ${schema}.census c ON c.CensusID = p.CensusID + WHERE c.PlotID = ? AND p.CensusID = ?`; + results = await runQuery(conn, query, [plotID, censusID]); + formMappedResults = results.map((row: any) => ({ + firstname: row.FirstName, + lastname: row.LastName, + role: row.RoleName, + roledescription: row.RoleDescription + })); + return new NextResponse(JSON.stringify(formMappedResults), { status: HTTPResponses.OK }); + case 'species': + query = `SELECT DISTINCT s.SpeciesCode AS SpeciesCode, f.Family AS Family, + g.Genus AS Genus, s.SpeciesName AS SpeciesName, s.SubspeciesName AS SubspeciesName, + s.IDLevel AS IDLevel, s.SpeciesAuthority AS SpeciesAuthority, s.SubspeciesAuthority AS SubspeciesAuthority + FROM ${schema}.species s + JOIN ${schema}.genus g ON g.GenusID = s.GenusID + JOIN ${schema}.family f ON f.FamilyID = g.FamilyID + JOIN ${schema}.trees t ON t.SpeciesID = s.SpeciesID + JOIN ${schema}.stems st ON st.TreeID = t.TreeID + JOIN ${schema}.quadrats q ON q.QuadratID = st.QuadratID + JOIN ${schema}.censusquadrat cq ON cq.QuadratID = q.QuadratID + WHERE q.PlotID = ? AND cq.CensusID = ?`; + results = await runQuery(conn, query, [plotID, censusID]); + formMappedResults = results.map((row: any) => ({ + spcode: row.SpeciesCode, + family: row.Family, + genus: row.Genus, + species: row.SpeciesName, + subspecies: row.SubspeciesName, + idlevel: row.IDLevel, + authority: row.SpeciesAuthority, + subspeciesauthority: row.SubspeciesAuthority + })); + return new NextResponse(JSON.stringify(formMappedResults), { status: HTTPResponses.OK }); + case 'quadrats': + query = `SELECT * FROM ${schema}.quadrats q + JOIN ${schema}.censusquadrat cq ON cq.QuadratID = q.QuadratID + WHERE q.PlotID = ? AND cq.CensusID = ?`; + results = await runQuery(conn, query, [plotID, censusID]); + formMappedResults = results.map((row: any) => ({ + quadrat: row.QuadratName, + startx: row.StartX, + starty: row.StartY, + coordinateunit: row.CoordinateUnits, + dimx: row.DimensionX, + dimy: row.DimensionY, + dimensionunit: row.DimensionUnits, + area: row.Area, + areaunit: row.AreaUnits, + quadratshape: row.QuadratShape + })); + return new NextResponse(JSON.stringify(formMappedResults), { status: HTTPResponses.OK }); + case 'measurements': + query = `SELECT st.StemTag AS StemTag, t.TreeTag AS TreeTag, s.SpeciesCode AS SpeciesCode, q.QuadratName AS QuadratName, + q.StartX AS StartX, q.StartY AS StartY, q.CoordinateUnits AS CoordinateUnits, cm.MeasuredDBH AS MeasuredDBH, cm.DBHUnit AS DBHUnit, + cm.MeasuredHOM AS MeasuredHOM, cm.HOMUnit AS HOMUnit, cm.MeasurementDate AS MeasurementDate, + (SELECT GROUP_CONCAT(ca.Code SEPARATOR '; ') + FROM ${schema}.cmattributes ca + WHERE ca.CoreMeasurementID = cm.CoreMeasurementID) AS Codes + FROM ${schema}.coremeasurements cm + JOIN ${schema}.stems st ON st.StemID = cm.StemID + JOIN ${schema}.trees t ON t.TreeID = st.TreeID + JOIN ${schema}.quadrats q ON q.QuadratID = st.QuadratID + JOIN ${schema}.censusquadrat cq ON cq.QuadratID = q.QuadratID + JOIN ${schema}.species s ON s.SpeciesID = t.SpeciesID + WHERE q.PlotID = ? AND cq.CensusID = ?`; + results = await runQuery(conn, query, [plotID, censusID]); + formMappedResults = results.map((row: any) => ({ + tag: row.TreeTag, + stemtag: row.StemTag, + spcode: row.SpeciesCode, + quadrat: row.QuadratName, + lx: row.StartX, + ly: row.StartY, + coordinateunit: row.CoordinateUnits, + dbh: row.MeasuredDBH, + dbhunit: row.DBHUnit, + hom: row.MeasuredHOM, + homunit: row.HOMUnit, + date: row.MeasurementDate, + codes: row.Codes + })); + return new NextResponse(JSON.stringify(formMappedResults), { status: HTTPResponses.OK }); + default: + throw new Error('incorrect data type passed in'); + } + } catch (e: any) { + throw new Error(e); + } finally { + if (conn) conn.release(); + } +} diff --git a/frontend/components/datagrids/applications/isolated/isolatedattributesdatagrid.tsx b/frontend/components/datagrids/applications/isolated/isolatedattributesdatagrid.tsx index e4ed6531..3a3dfed9 100644 --- a/frontend/components/datagrids/applications/isolated/isolatedattributesdatagrid.tsx +++ b/frontend/components/datagrids/applications/isolated/isolatedattributesdatagrid.tsx @@ -9,6 +9,7 @@ import { AttributeGridColumns } from '@/components/client/datagridcolumns'; import { FormType } from '@/config/macros/formdetails'; import IsolatedDataGridCommons from '@/components/datagrids/isolateddatagridcommons'; import MultilineModal from '@/components/datagrids/applications/multiline/multilinemodal'; +import { useSiteContext } from '@/app/contexts/userselectionprovider'; export default function IsolatedAttributesDataGrid() { const initialAttributesRDSRow = { @@ -21,6 +22,7 @@ export default function IsolatedAttributesDataGrid() { const [isUploadModalOpen, setIsUploadModalOpen] = useState(false); const [isManualEntryFormOpen, setIsManualEntryFormOpen] = useState(false); const { data: session } = useSession(); + const currentSite = useSiteContext(); return ( <> diff --git a/frontend/components/datagrids/isolateddatagridcommons.tsx b/frontend/components/datagrids/isolateddatagridcommons.tsx index 92859a5f..0b2970d2 100644 --- a/frontend/components/datagrids/isolateddatagridcommons.tsx +++ b/frontend/components/datagrids/isolateddatagridcommons.tsx @@ -50,10 +50,12 @@ import { StyledDataGrid } from '@/config/styleddatagrid'; import ConfirmationDialog from '@/components/datagrids/confirmationdialog'; import { randomId } from '@mui/x-data-grid-generator'; import SkipReEnterDataModal from '@/components/datagrids/skipreentrydatamodal'; +import { FileDownloadTwoTone } from '@mui/icons-material'; +import { FormType, getTableHeaders } from '@/config/macros/formdetails'; type EditToolbarProps = EditToolbarCustomProps & GridToolbarProps & ToolbarPropsOverrides; -const EditToolbar = ({ handleAddNewRow, handleRefresh, handleExportAll, locked, filterModel }: EditToolbarProps) => { +const EditToolbar = ({ handleAddNewRow, handleRefresh, handleExportAll, handleExportCSV, locked, filterModel }: EditToolbarProps) => { if (!handleAddNewRow || !handleRefresh) return <>; const handleExportClick = async () => { if (!handleExportAll) return; @@ -82,6 +84,9 @@ const EditToolbar = ({ handleAddNewRow, handleRefresh, handleExportAll, locked, + ); }; @@ -221,6 +226,120 @@ export default function IsolatedDataGridCommons(props: Readonly { + switch (gridType) { + case 'attributes': + const aResponse = await fetch( + `/api/formdownload/attributes/${currentSite?.schemaName ?? ''}/${currentPlot?.plotID ?? 0}/${currentCensus?.dateRanges[0].censusID ?? 0}`, + { method: 'GET' } + ); + const aData = await aResponse.json(); + let aCSVRows = + getTableHeaders(FormType.attributes) + .map(row => row.label) + .join(',') + '\n'; + aData.forEach((row: any) => { + const values = getTableHeaders(FormType.attributes) + .map(rowHeader => rowHeader.label) + .map(header => row[header]); + aCSVRows += values.join(',') + '\n'; + }); + const aBlob = new Blob([aCSVRows], { + type: 'text/csv;charset=utf-8;' + }); + const aURL = URL.createObjectURL(aBlob); + const aLink = document.createElement('a'); + aLink.href = aURL; + aLink.download = `attributesform_${currentSite?.schemaName ?? ''}_${currentPlot?.plotName ?? ''}_${currentCensus?.plotCensusNumber ?? 0}.csv`; + document.body.appendChild(aLink); + aLink.click(); + document.body.removeChild(aLink); + break; + case 'quadrats': + const qResponse = await fetch( + `/api/formdownload/quadrats/${currentSite?.schemaName ?? ''}/${currentPlot?.plotID ?? 0}/${currentCensus?.dateRanges[0].censusID ?? 0}`, + { method: 'GET' } + ); + const qData = await qResponse.json(); + let qCSVRows = + getTableHeaders(FormType.quadrats) + .map(row => row.label) + .join(',') + '\n'; + qData.forEach((row: any) => { + const values = getTableHeaders(FormType.quadrats) + .map(rowHeader => rowHeader.label) + .map(header => row[header]); + qCSVRows += values.join(',') + '\n'; + }); + const qBlob = new Blob([qCSVRows], { + type: 'text/csv;charset=utf-8;' + }); + const qURL = URL.createObjectURL(qBlob); + const qLink = document.createElement('a'); + qLink.href = qURL; + qLink.download = `quadratsform_${currentSite?.schemaName ?? ''}_${currentPlot?.plotName ?? ''}_${currentCensus?.plotCensusNumber ?? 0}.csv`; + document.body.appendChild(qLink); + qLink.click(); + document.body.removeChild(qLink); + break; + case 'personnel': + const pResponse = await fetch( + `/api/formdownload/personnel/${currentSite?.schemaName ?? ''}/${currentPlot?.plotID ?? 0}/${currentCensus?.dateRanges[0].censusID ?? 0}`, + { method: 'GET' } + ); + const pData = await pResponse.json(); + let pCSVRows = + getTableHeaders(FormType.personnel) + .map(row => row.label) + .join(',') + '\n'; + pData.forEach((row: any) => { + const values = getTableHeaders(FormType.personnel) + .map(rowHeader => rowHeader.label) + .map(header => row[header]); + pCSVRows += values.join(',') + '\n'; + }); + const pBlob = new Blob([pCSVRows], { + type: 'text/csv;charset=utf-8;' + }); + const pURL = URL.createObjectURL(pBlob); + const pLink = document.createElement('a'); + pLink.href = pURL; + pLink.download = `personnelform_${currentSite?.schemaName ?? ''}_${currentPlot?.plotName ?? ''}_${currentCensus?.plotCensusNumber ?? 0}.csv`; + document.body.appendChild(pLink); + pLink.click(); + document.body.removeChild(pLink); + break; + case 'species': + case 'alltaxonomiesview': + const sResponse = await fetch( + `/api/formdownload/species/${currentSite?.schemaName ?? ''}/${currentPlot?.plotID ?? 0}/${currentCensus?.dateRanges[0].censusID ?? 0}`, + { method: 'GET' } + ); + const sData = await sResponse.json(); + let sCSVRows = + getTableHeaders(FormType.species) + .map(row => row.label) + .join(',') + '\n'; + sData.forEach((row: any) => { + const values = getTableHeaders(FormType.species) + .map(rowHeader => rowHeader.label) + .map(header => row[header]); + sCSVRows += values.join(',') + '\n'; + }); + const sBlob = new Blob([sCSVRows], { + type: 'text/csv;charset=utf-8;' + }); + const sURL = URL.createObjectURL(sBlob); + const sLink = document.createElement('a'); + sLink.href = sURL; + sLink.download = `speciesform_${currentSite?.schemaName ?? ''}_${currentPlot?.plotName ?? ''}_${currentCensus?.plotCensusNumber ?? 0}.csv`; + document.body.appendChild(sLink); + sLink.click(); + document.body.removeChild(sLink); + break; + } + }, [currentPlot, currentCensus, currentSite, gridType]); + const openConfirmationDialog = useCallback( (actionType: 'save' | 'delete', actionId: GridRowId) => { setPendingAction({ actionType, actionId }); @@ -864,10 +983,10 @@ export default function IsolatedDataGridCommons(props: Readonly 'auto'} /> @@ -876,19 +995,6 @@ export default function IsolatedDataGridCommons(props: Readonly )} - {/*{isDialogOpen && promiseArguments && (*/} - {/* */} - {/*)}*/} {isDialogOpen && promiseArguments && ( void>(fn: T, delay: number): T { let timeoutId: ReturnType; @@ -70,7 +71,7 @@ function debounce void>(fn: T, delay: number): T { type EditToolbarProps = EditToolbarCustomProps & GridToolbarProps & ToolbarPropsOverrides; -const EditToolbar = ({ handleAddNewRow, handleRefresh, handleExportAll, handleExportErrors, locked, filterModel }: EditToolbarProps) => { +const EditToolbar = ({ handleAddNewRow, handleRefresh, handleExportAll, handleExportErrors, handleExportCSV, locked, filterModel }: EditToolbarProps) => { const handleExportClick = async () => { if (!handleExportAll) return; const fullData = await handleExportAll(filterModel); @@ -113,9 +114,12 @@ const EditToolbar = ({ handleAddNewRow, handleRefresh, handleExportAll, handleEx - + ); }; @@ -192,6 +196,34 @@ export default function MeasurementsCommons(props: Readonly { + const response = await fetch( + `/api/formdownload/measurements/${currentSite?.schemaName ?? ''}/${currentPlot?.plotID ?? 0}/${currentCensus?.dateRanges[0].censusID ?? 0}`, + { method: 'GET' } + ); + const data = await response.json(); + let csvRows = + getTableHeaders(FormType.measurements) + .map(row => row.label) + .join(',') + '\n'; + data.forEach((row: any) => { + const values = getTableHeaders(FormType.measurements) + .map(rowHeader => rowHeader.label) + .map(header => row[header]); + csvRows += values.join(',') + '\n'; + }); + const blob = new Blob([csvRows], { + type: 'text/csv;charset=utf-8;' + }); + const url = URL.createObjectURL(blob); + const link = document.createElement('a'); + link.href = url; + link.download = `measurementsform_${currentSite?.schemaName ?? ''}_${currentPlot?.plotName ?? ''}_${currentCensus?.plotCensusNumber ?? 0}.csv`; + document.body.appendChild(link); + link.click(); + document.body.removeChild(link); + }, [currentPlot, currentCensus, currentSite, gridType]); + // helper functions for usage: const handleSortModelChange = (newModel: GridSortModel) => { setSortModel(newModel); @@ -932,7 +964,8 @@ export default function MeasurementsCommons(props: Readonly 'auto'} diff --git a/frontend/config/datagridhelpers.ts b/frontend/config/datagridhelpers.ts index a79fc9a4..3b7f2434 100644 --- a/frontend/config/datagridhelpers.ts +++ b/frontend/config/datagridhelpers.ts @@ -170,6 +170,7 @@ export interface EditToolbarCustomProps { handleAddNewRow?: () => Promise; handleRefresh?: () => Promise; handleExportAll?: (filterModel?: GridFilterModel) => Promise; + handleExportCSV?: () => Promise; filterModel?: GridFilterModel; locked?: boolean; } diff --git a/frontend/config/macros/formdetails.ts b/frontend/config/macros/formdetails.ts index 637be4e5..dd136df6 100644 --- a/frontend/config/macros/formdetails.ts +++ b/frontend/config/macros/formdetails.ts @@ -77,7 +77,7 @@ export const TableHeadersByFormType: Record = { [FormType.arcgis_xlsx]: arcgisHeaders }; -export function getTableHeaders(formType: FormType, _usesSubquadrats: boolean): { label: string }[] { +export function getTableHeaders(formType: FormType, _usesSubquadrats = false): { label: string }[] { return TableHeadersByFormType[formType]; }