diff --git a/__tests__/e2e/trees.spec.ts b/__tests__/e2e/trees.spec.ts index 8662ec01..17192ca2 100644 --- a/__tests__/e2e/trees.spec.ts +++ b/__tests__/e2e/trees.spec.ts @@ -2,21 +2,47 @@ import supertest from 'supertest'; import app from '../../server/app'; describe('trees', () => { - it('trees/{id}', async () => { - const response = await supertest(app).get('/trees/952022'); - expect(response.status).toBe(200); - expect(response.body).toMatchObject({ - id: 952022, - lat: expect.anything(), - lon: expect.anything(), - species_id: 113, - species_name: 'bob', - country_name: 'China', - country_id: 6632544, - organization_id: 11, - organization_name: 'FCC', - }); - }); + it( + 'trees/{id}', + async () => { + const response = await supertest(app).get('/trees/192'); + expect(response.status).toBe(200); + expect(response.body).toMatchObject({ + id: 192, + lat: expect.anything(), + lon: expect.anything(), + species_id: 4, + species_name: 'species_name_3', + country_name: 'Ashmore and Cartier Islands', + country_id: 230, + organization_id: 13, + organization_name: 'ISAP', + }); + }, + 1000 * 30, + ); + + it( + 'trees/{uuid}', + async () => { + const response = await supertest(app).get( + '/trees/c48ebfc0-bbe4-4a3a-8cff-7e5f4ff12977', + ); + expect(response.status).toBe(200); + expect(response.body).toMatchObject({ + id: 270, + lat: expect.anything(), + lon: expect.anything(), + species_id: 2, + species_name: 'species_name_3', + country_name: 'Sierra Leone', + country_id: 64, + organization_id: 5, + organization_name: 'UEMG', + }); + }, + 1000 * 30, + ); it('Unknown tree', async () => { const response = await supertest(app).get('/trees/1'); @@ -31,14 +57,6 @@ describe('trees', () => { }); }); - it('trees?limit=1&offset=0', async () => { - const response = await supertest(app).get('/trees?limit=1&offset=0'); - expect(response.status).toBe(200); - expect(response.body).toMatchObject({ - trees: expect.anything(), - }); - }); - it( 'trees?limit=1&organization_id=11', async () => { @@ -57,19 +75,20 @@ describe('trees', () => { ); it( - 'trees?startDate=2021-02-26&endDate=2021-12-22', + 'trees?startDate=2022-02-23&endDate=2022-02-24', async () => { const response = await supertest(app).get( - '/trees?startDate=2021-02-26&endDate=2021-12-22', + '/trees?startDate=2022-02-23&endDate=2022-02-24', ); expect(response.status).toBe(200); + expect(response.body.total).toBe(96); for (let i = 0; i < response.body.trees.length; i++) { expect( new Date(response.body.trees[i].time_created).getTime(), - ).toBeGreaterThanOrEqual(new Date('2021-02-26T00:00:00Z').getTime()); + ).toBeGreaterThanOrEqual(new Date('2022-02-23T00:00:00Z').getTime()); expect( new Date(response.body.trees[i].time_created).getTime(), - ).toBeLessThan(new Date('2021-12-23T00:00:00Z').getTime()); + ).toBeLessThan(new Date('2022-02-24T00:00:00Z').getTime()); } }, 1000 * 60, @@ -83,54 +102,66 @@ describe('trees', () => { // expect(response.body).toMatchObject({ // trees: expect.anything(), // }); + expect(response.body.trees.length).toBe(3); expect(response.body.trees[0]).toMatchObject({ id: expect.any(Number), }); }, - 1000 * 10, + 1000 * 30, ); it( 'trees?tag=photoless', async () => { const response = await supertest(app).get('/trees?tag=photoless'); - const expectedIds = [186685, 878654]; + const expectedIds = [238]; expect(response.status).toBe(200); - expect(response.body.total).toBe(2); - const returnedIds = [ - response.body.trees[0].id, - response.body.trees[1].id, - ]; + expect(response.body.total).toBe(1); + const returnedIds = [response.body.trees[0].id]; expect(returnedIds).toEqual(expectedIds); }, 1000 * 30, ); it( - 'trees?planter_id=3584&desc=true', + 'trees?planter_id=5840&desc=true', + async () => { + const response = await supertest(app).get( + '/trees?planter_id=5840&limit=1&order_by=id', + ); + expect(response.status).toBe(200); + expect(response.body.trees[0]).toMatchObject({ + id: 270, + planter_id: 5840, + }); + }, + 1000 * 30, + ); + + it( + 'trees?planter_id=5840&desc=false', async () => { const response = await supertest(app).get( - '/trees?planter_id=3584&limit=1&order_by=created_at', + '/trees?planter_id=5840&order_by=id&desc=false&limit=1', ); expect(response.status).toBe(200); expect(response.body.trees[0]).toMatchObject({ - id: 938209, - planter_id: 3584, + id: 171, + planter_id: 5840, }); }, 1000 * 30, ); it( - 'trees?planter_id=3584&desc=false', + 'trees?wallet_id=9b25795c-a07b-4487-92cf-b9b784d5dfc0', async () => { const response = await supertest(app).get( - '/trees?planter_id=3584&order_by=created_at&desc=false&limit=1', + '/trees?wallet_id=9b25795c-a07b-4487-92cf-b9b784d5dfc0', ); expect(response.status).toBe(200); expect(response.body.trees[0]).toMatchObject({ - id: 937190, - planter_id: 3584, + wallet_id: '9b25795c-a07b-4487-92cf-b9b784d5dfc0', }); }, 1000 * 30, diff --git a/package-lock.json b/package-lock.json index 60c6280d..db7564d7 100644 --- a/package-lock.json +++ b/package-lock.json @@ -1,12 +1,12 @@ { "name": "treetracker-query-api", - "version": "1.70.7", + "version": "1.73.0", "lockfileVersion": 2, "requires": true, "packages": { "": { "name": "treetracker-query-api", - "version": "1.70.7", + "version": "1.73.0", "license": "GPL-3.0-or-later", "dependencies": { "@sentry/node": "^5.1.0", diff --git a/server/infra/database/TreeRepository.ts b/server/infra/database/TreeRepository.ts index 4506b2ed..dda8a766 100644 --- a/server/infra/database/TreeRepository.ts +++ b/server/infra/database/TreeRepository.ts @@ -6,7 +6,7 @@ import Session from './Session'; export default class TreeRepository extends BaseRepository { constructor(session: Session) { - super('trees', session); + super('denormalized.trees_denormalized', session); } async getById(id: number) { @@ -14,34 +14,22 @@ export default class TreeRepository extends BaseRepository { .getDB() .select( this.session.getDB().raw(` - trees.*, - tree_species.id as species_id, - tree_species.name as species_name, - tree_species.desc as species_desc, - region.name as country_name, - region.id as country_id, - entity.id as organization_id, - entity.name as organization_name, - wallet.wallet.id as wallet_id, - wallet.wallet.name as wallet_name, - wallet.token.id as token_id - from trees - left JOIN planter - on trees.planter_id = planter.id - left JOIN entity - on entity.id = planter.organization_id - left JOIN tree_species - on trees.species_id = tree_species.id - left JOIN region - on ST_WITHIN(trees.estimated_geometric_location, region.geom) - and region.type_id in (select id from region_type where type = 'country') - left JOIN wallet.token - on wallet.token.capture_id::text = trees.uuid::text - left JOIN wallet.wallet - on wallet.token.wallet_id = wallet.wallet.id + td.*, td.planting_organization_id as organization_id, td.species as species_name, + o."name" as organization_name, r."name" as country_name, ts."desc" as species_desc, w."name" as wallet_name + FROM + denormalized.trees_denormalized td + LEFT JOIN public.organizations o + on td.planting_organization_id = o.id + LEFT JOIN public.region r + on td.country_id = cast(r."metadata" ->>'id' as integer) + LEFT JOIN public.tree_species ts + on ts.id = td.species_id + LEFT JOIN wallet.wallet w + on w.id = td.wallet_id `), ) - .where('trees.id', id) + .where('r.type_id', 6) + .where('td.id', id) .first(); if (!object) { @@ -55,34 +43,22 @@ export default class TreeRepository extends BaseRepository { .getDB() .select( this.session.getDB().raw(` - trees.*, - tree_species.id as species_id, - tree_species.name as species_name, - tree_species.desc as species_desc, - region.name as country_name, - region.id as country_id, - entity.id as organization_id, - entity.name as organization_name, - wallet.wallet.id as wallet_id, - wallet.wallet.name as wallet_name, - wallet.token.id as token_id - from trees - left JOIN planter - on trees.planter_id = planter.id - left JOIN entity - on entity.id = planter.organization_id - left JOIN tree_species - on trees.species_id = tree_species.id - left JOIN region - on ST_WITHIN(trees.estimated_geometric_location, region.geom) - and region.type_id in (select id from region_type where type = 'country') - left JOIN wallet.token - on wallet.token.capture_id::text = trees.uuid::text - left JOIN wallet.wallet - on wallet.token.wallet_id = wallet.wallet.id + td.*, td.planting_organization_id as organization_id, td.species as species_name, + o."name" as organization_name, r."name" as country_name, ts."desc" as species_desc, w."name" as wallet_name + FROM + denormalized.trees_denormalized td + LEFT JOIN public.organizations o + on td.planting_organization_id = o.id + LEFT JOIN public.region r + on td.country_id = cast(r."metadata" ->>'id' as integer) + LEFT JOIN public.tree_species ts + on ts.id = td.species_id + LEFT JOIN wallet.wallet w + on w.id = td.wallet_id `), ) - .where('trees.uuid', uuid) + .where('r.type_id', 6) + .where('td.uuid', uuid) .first(); if (!object) { @@ -103,45 +79,36 @@ export default class TreeRepository extends BaseRepository { if (totalCount) { const totalSql = ` - SELECT - COUNT(*) - FROM trees - LEFT JOIN planter ON trees.planter_id = planter.id - WHERE - ( - planter.organization_id in ( SELECT entity_id from getEntityRelationshipChildren(${organization_id})) - OR - trees.planting_organization_id = ${organization_id} - ) and trees.active = true + SELECT + count(*) + FROM + denormalized.trees_denormalized td + WHERE + td.active = true + and td.planting_organization_id = ${organization_id} `; const total = await this.session.getDB().raw(totalSql); return parseInt(total.rows[0].count.toString()); } const sql = ` - SELECT - trees.*, - tree_species.id as species_id, - tree_species.name as species_name, - region.id as country_id, - region.name as country_name, - entity.id as organization_id, - entity.name as organization_name - FROM trees - LEFT JOIN planter ON trees.planter_id = planter.id - LEFT JOIN entity ON entity.id = planter.organization_id - LEFT JOIN tree_species - on trees.species_id = tree_species.id - LEFT JOIN region - on ST_WITHIN(trees.estimated_geometric_location, region.geom) - and region.type_id in (select id from region_type where type = 'country') - WHERE - ( - planter.organization_id in ( SELECT entity_id from getEntityRelationshipChildren(${organization_id})) - OR - trees.planting_organization_id = ${organization_id} - ) - and trees.active = true + SELECT + td.*, td.planting_organization_id as organization_id, td.species as species_name, + o."name" as organization_name, r."name" as country_name, ts."desc" as species_desc, w."name" as wallet_name + FROM + denormalized.trees_denormalized td + LEFT JOIN public.organizations o + on td.planting_organization_id = o.id + LEFT JOIN public.region r + on td.country_id = cast(r."metadata" ->>'id' as integer) + LEFT JOIN public.tree_species ts + on ts.id = td.species_id + LEFT JOIN wallet.wallet w + on w.id = td.wallet_id + WHERE + r.type_id = 6 + and td.planting_organization_id = ${organization_id} + and td.active = true LIMIT ${limit} OFFSET ${offset} `; @@ -162,39 +129,39 @@ export default class TreeRepository extends BaseRepository { if (totalCount) { const totalSql = ` - SELECT - COUNT(*) - FROM trees - WHERE time_created >= '${startDateISO}'::timestamp - AND time_created < '${endDateISO}'::timestamp - and trees.active = true + SELECT + COUNT(*) + FROM denormalized.trees_denormalized td + WHERE + td.time_created >= '${startDateISO}'::timestamp + and td.time_created < '${endDateISO}'::timestamp + and td.active = true `; const total = await this.session.getDB().raw(totalSql); return parseInt(total.rows[0].count.toString()); } const sql = ` - SELECT - trees.*, - tree_species.id as species_id, - tree_species.name as species_name, - region.id as country_id, - region.name as country_name, - entity.id as organization_id, - entity.name as organization_name - FROM trees - LEFT JOIN planter ON trees.planter_id = planter.id - LEFT JOIN entity ON entity.id = planter.organization_id - LEFT JOIN tree_species - on trees.species_id = tree_species.id - LEFT JOIN region - on ST_WITHIN(trees.estimated_geometric_location, region.geom) - and region.type_id in (select id from region_type where type = 'country') - WHERE time_created >= '${startDateISO}'::timestamp - AND time_created < '${endDateISO}'::timestamp - and trees.active = true - LIMIT ${limit} - OFFSET ${offset} + SELECT + td.*, td.planting_organization_id as organization_id, td.species as species_name, + o."name" as organization_name, r."name" as country_name, ts."desc" as species_desc, w."name" as wallet_name + FROM + denormalized.trees_denormalized td + LEFT JOIN public.organizations o + on td.planting_organization_id = o.id + LEFT JOIN public.region r + on td.country_id = cast(r."metadata" ->>'id' as integer) + LEFT JOIN public.tree_species ts + on ts.id = td.species_id + LEFT JOIN wallet.wallet w + on w.id = td.wallet_id + WHERE + r.type_id = 6 + and td.time_created >= '${startDateISO}'::timestamp + and td.time_created < '${endDateISO}'::timestamp + and td.active = true + LIMIT ${limit} + OFFSET ${offset} `; const object = await this.session.getDB().raw(sql); return object.rows; @@ -207,42 +174,39 @@ export default class TreeRepository extends BaseRepository { const totalSql = ` SELECT COUNT(*) - FROM trees - INNER JOIN tree_tag - on tree_tag.tree_id = trees.id - INNER JOIN tag - on tree_tag.tag_id = tag.id + FROM denormalized.trees_denormalized td + INNER JOIN public.tree_tag tt + on tt.tree_id = td.id + INNER JOIN tag t + on tt.tag_id = t.id WHERE - tag.tag_name in ('${tag}') - and trees.active = true + t.tag_name in ('${tag}') + and td.active = true `; const total = await this.session.getDB().raw(totalSql); return parseInt(total.rows[0].count.toString()); } const sql = ` SELECT - trees.*, - tree_species.id as species_id, - tree_species.name as species_name, - region.id as country_id, - region.name as country_name, - entity.id as organization_id, - entity.name as organization_name - FROM trees - LEFT JOIN planter ON trees.planter_id = planter.id - LEFT JOIN entity ON entity.id = planter.organization_id - LEFT JOIN tree_species - on trees.species_id = tree_species.id - LEFT JOIN region - on ST_WITHIN(trees.estimated_geometric_location, region.geom) - and region.type_id in (select id from region_type where type = 'country') - INNER JOIN tree_tag - on tree_tag.tree_id = trees.id - INNER JOIN tag - on tree_tag.tag_id = tag.id + td.*, td.planting_organization_id as organization_id, td.species as species_name, + o."name" as organization_name, r."name" as country_name, ts."desc" as species_desc, w."name" as wallet_name + FROM + denormalized.trees_denormalized td + LEFT JOIN public.organizations o + on td.planting_organization_id = o.id + LEFT JOIN public.region r + on td.country_id = cast(r."metadata" ->>'id' as integer) + LEFT JOIN public.tree_species ts + on ts.id = td.species_id + LEFT JOIN wallet.wallet w + on w.id = td.wallet_id + INNER JOIN tree_tag tt + on tt.tree_id = td.id + INNER JOIN tag t + on tt.tag_id = t.id WHERE - tag.tag_name in ('${tag}') - and trees.active = true + t.tag_name in ('${tag}') + and td.active = true LIMIT ${limit} OFFSET ${offset} `; @@ -252,20 +216,27 @@ export default class TreeRepository extends BaseRepository { async getFeaturedTree() { const sql = ` - SELECT trees.* ,tree_species.name as species_name, - country.id as country_id, country.name as country_name - FROM trees - join ( + SELECT + td.*, td.planting_organization_id as organization_id, td.species as species_name, + o."name" as organization_name, r."name" as country_name, ts."desc" as species_desc, w."name" as wallet_name + FROM + denormalized.trees_denormalized td + LEFT JOIN public.organizations o + on td.planting_organization_id = o.id + LEFT JOIN public.region r + on td.country_id = cast(r."metadata" ->>'id' as integer) + LEFT JOIN public.tree_species ts + on ts.id = td.species_id + LEFT JOIN wallet.wallet w + on w.id = td.wallet_id + JOIN ( --- convert json array to row SELECT json_array_elements(data -> 'trees') AS tree_id FROM webmap.config WHERE name = 'featured-tree' ) AS t ON --- cast json type t.tree_id to integer - t.tree_id::text::integer = trees.id - LEFT JOIN tree_species - ON trees.species_id = tree_species.id - LEFT JOIN region as country ON ST_WITHIN(trees.estimated_geometric_location, country.geom) - and country.type_id in - (SELECT id FROM region_type WHERE type = 'country') + t.tree_id::text::integer = td.id + WHERE + r.type_id = 6 `; const object = await this.session.getDB().raw(sql); return object.rows; @@ -280,24 +251,35 @@ export default class TreeRepository extends BaseRepository { if (totalCount) { const totalSql = ` - SELECT - COUNT(*) - FROM trees - LEFT JOIN wallet.token ON token.capture_id::text = trees.uuid - WHERE wallet.token.wallet_id = '${wallet_id}' - and trees.active = true + SELECT + COUNT(*) + FROM denormalized.trees_denormalized td + WHERE + td.wallet_id = '${wallet_id}' + and td.active = true `; const total = await this.session.getDB().raw(totalSql); return parseInt(total.rows[0].count.toString()); } const sql = ` - SELECT - trees.* - FROM trees - LEFT JOIN wallet.token ON token.capture_id::text = trees.uuid - WHERE wallet.token.wallet_id = '${wallet_id}' - and trees.active = true + SELECT + td.*, td.planting_organization_id as organization_id, td.species as species_name, + o."name" as organization_name, r."name" as country_name, ts."desc" as species_desc, w."name" as wallet_name + FROM + denormalized.trees_denormalized td + LEFT JOIN public.organizations o + on td.planting_organization_id = o.id + LEFT JOIN public.region r + on td.country_id = cast(r."metadata" ->>'id' as integer) + LEFT JOIN public.tree_species ts + on ts.id = td.species_id + LEFT JOIN wallet.wallet w + on w.id = td.wallet_id + WHERE + r.type_id = 6 + and td.wallet_id = '${wallet_id}' + and td.active = true LIMIT ${limit} OFFSET ${offset} `; diff --git a/server/routers/treesRouter.ts b/server/routers/treesRouter.ts index efb09bef..28b5c5da 100644 --- a/server/routers/treesRouter.ts +++ b/server/routers/treesRouter.ts @@ -108,8 +108,9 @@ router.get( } const result = await TreeModel.getByFilter(repo)(filter, options); + const countResult = await TreeModel.countByFilter(repo)(filter, options); res.send({ - total: await TreeModel.countByFilter(repo)(filter, options), + total: countResult, offset, limit, trees: result,