|
| 1 | +import FilterOptions from 'interfaces/FilterOptions'; |
| 2 | +import Tree from 'interfaces/Tree'; |
| 3 | +import HttpError from 'utils/HttpError'; |
| 4 | +import BaseRepository from './BaseRepository'; |
| 5 | +import Session from './Session'; |
| 6 | + |
| 7 | +export default class TreeRepositoryV2 extends BaseRepository<Tree> { |
| 8 | + constructor(session: Session) { |
| 9 | + super('treetracker.tree', session); |
| 10 | + } |
| 11 | + |
| 12 | + async getById(id: string | number) { |
| 13 | + const object = await this.session |
| 14 | + .getDB() |
| 15 | + .select() |
| 16 | + .from(this.tableName) |
| 17 | + .where('id', id) |
| 18 | + .first(); |
| 19 | + |
| 20 | + if (!object) { |
| 21 | + throw new HttpError(404, `Can not find ${this.tableName} by id:${id}!`); |
| 22 | + } |
| 23 | + return object; |
| 24 | + } |
| 25 | + |
| 26 | + async getByOrganization( |
| 27 | + organization_id: number, |
| 28 | + options: FilterOptions, |
| 29 | + totalCount = false, |
| 30 | + ) { |
| 31 | + const { limit, offset } = options; |
| 32 | + |
| 33 | + if (totalCount) { |
| 34 | + const totalSql = ` |
| 35 | + SELECT |
| 36 | + COUNT(*) |
| 37 | + FROM trees |
| 38 | + LEFT JOIN planter ON trees.planter_id = planter.id |
| 39 | + WHERE |
| 40 | + planter.organization_id in ( SELECT entity_id from getEntityRelationshipChildren(${organization_id})) |
| 41 | + `; |
| 42 | + const total = await this.session.getDB().raw(totalSql); |
| 43 | + return parseInt(total.rows[0].count.toString()); |
| 44 | + } |
| 45 | + |
| 46 | + const sql = ` |
| 47 | + SELECT |
| 48 | + trees.*, |
| 49 | + tree_species.id as species_id, |
| 50 | + tree_species.name as species_name, |
| 51 | + region.id as country_id, |
| 52 | + region.name as country_name, |
| 53 | + entity.id as organization_id, |
| 54 | + entity.name as organization_name |
| 55 | + FROM trees |
| 56 | + LEFT JOIN planter ON trees.planter_id = planter.id |
| 57 | + LEFT JOIN entity ON entity.id = planter.organization_id |
| 58 | + LEFT JOIN tree_species |
| 59 | + on trees.species_id = tree_species.id |
| 60 | + LEFT JOIN region |
| 61 | + on ST_WITHIN(trees.estimated_geometric_location, region.geom) |
| 62 | + and region.type_id in (select id from region_type where type = 'country') |
| 63 | + WHERE |
| 64 | + planter.organization_id in ( SELECT entity_id from getEntityRelationshipChildren(${organization_id})) |
| 65 | + LIMIT ${limit} |
| 66 | + OFFSET ${offset} |
| 67 | + `; |
| 68 | + const object = await this.session.getDB().raw(sql); |
| 69 | + return object.rows; |
| 70 | + } |
| 71 | + |
| 72 | + async getByDateRange( |
| 73 | + date_range: { startDate: string; endDate: string }, |
| 74 | + options: FilterOptions, |
| 75 | + totalCount = false, |
| 76 | + ) { |
| 77 | + const { limit, offset } = options; |
| 78 | + const startDateISO = `${date_range.startDate}T00:00:00.000Z`; |
| 79 | + const endDateISO = new Date( |
| 80 | + new Date(`${date_range.endDate}T00:00:00.000Z`).getTime() + 86400000, |
| 81 | + ).toISOString(); |
| 82 | + |
| 83 | + if (totalCount) { |
| 84 | + const totalSql = ` |
| 85 | + SELECT |
| 86 | + COUNT(*) |
| 87 | + FROM trees |
| 88 | + WHERE time_created >= '${startDateISO}'::timestamp |
| 89 | + AND time_created < '${endDateISO}'::timestamp |
| 90 | + `; |
| 91 | + const total = await this.session.getDB().raw(totalSql); |
| 92 | + return parseInt(total.rows[0].count.toString()); |
| 93 | + } |
| 94 | + |
| 95 | + const sql = ` |
| 96 | + SELECT |
| 97 | + trees.*, |
| 98 | + tree_species.id as species_id, |
| 99 | + tree_species.name as species_name, |
| 100 | + region.id as country_id, |
| 101 | + region.name as country_name, |
| 102 | + entity.id as organization_id, |
| 103 | + entity.name as organization_name |
| 104 | + FROM trees |
| 105 | + LEFT JOIN planter ON trees.planter_id = planter.id |
| 106 | + LEFT JOIN entity ON entity.id = planter.organization_id |
| 107 | + LEFT JOIN tree_species |
| 108 | + on trees.species_id = tree_species.id |
| 109 | + LEFT JOIN region |
| 110 | + on ST_WITHIN(trees.estimated_geometric_location, region.geom) |
| 111 | + and region.type_id in (select id from region_type where type = 'country') |
| 112 | + WHERE time_created >= '${startDateISO}'::timestamp |
| 113 | + AND time_created < '${endDateISO}'::timestamp |
| 114 | + LIMIT ${limit} |
| 115 | + OFFSET ${offset} |
| 116 | + `; |
| 117 | + const object = await this.session.getDB().raw(sql); |
| 118 | + return object.rows; |
| 119 | + } |
| 120 | + |
| 121 | + async getByTag(tag: string, options: FilterOptions, totalCount = false) { |
| 122 | + const { limit, offset } = options; |
| 123 | + |
| 124 | + if (totalCount) { |
| 125 | + const totalSql = ` |
| 126 | + SELECT |
| 127 | + COUNT(*) |
| 128 | + FROM trees |
| 129 | + INNER JOIN tree_tag |
| 130 | + on tree_tag.tree_id = trees.id |
| 131 | + INNER JOIN tag |
| 132 | + on tree_tag.tag_id = tag.id |
| 133 | + WHERE |
| 134 | + tag.tag_name in ('${tag}') |
| 135 | + `; |
| 136 | + const total = await this.session.getDB().raw(totalSql); |
| 137 | + return parseInt(total.rows[0].count.toString()); |
| 138 | + } |
| 139 | + const sql = ` |
| 140 | + SELECT |
| 141 | + trees.*, |
| 142 | + tree_species.id as species_id, |
| 143 | + tree_species.name as species_name, |
| 144 | + region.id as country_id, |
| 145 | + region.name as country_name, |
| 146 | + entity.id as organization_id, |
| 147 | + entity.name as organization_name |
| 148 | + FROM trees |
| 149 | + LEFT JOIN planter ON trees.planter_id = planter.id |
| 150 | + LEFT JOIN entity ON entity.id = planter.organization_id |
| 151 | + LEFT JOIN tree_species |
| 152 | + on trees.species_id = tree_species.id |
| 153 | + LEFT JOIN region |
| 154 | + on ST_WITHIN(trees.estimated_geometric_location, region.geom) |
| 155 | + and region.type_id in (select id from region_type where type = 'country') |
| 156 | + INNER JOIN tree_tag |
| 157 | + on tree_tag.tree_id = trees.id |
| 158 | + INNER JOIN tag |
| 159 | + on tree_tag.tag_id = tag.id |
| 160 | + WHERE |
| 161 | + tag.tag_name in ('${tag}') |
| 162 | + LIMIT ${limit} |
| 163 | + OFFSET ${offset} |
| 164 | + `; |
| 165 | + const object = await this.session.getDB().raw(sql); |
| 166 | + return object.rows; |
| 167 | + } |
| 168 | + |
| 169 | + async getFeaturedTree() { |
| 170 | + const sql = ` |
| 171 | + SELECT trees.* ,tree_species.name as species_name, |
| 172 | + country.id as country_id, country.name as country_name |
| 173 | + FROM trees |
| 174 | + join ( |
| 175 | + --- convert json array to row |
| 176 | + SELECT json_array_elements(data -> 'trees') AS tree_id FROM webmap.config WHERE name = 'featured-tree' |
| 177 | + ) AS t ON |
| 178 | + --- cast json type t.tree_id to integer |
| 179 | + t.tree_id::text::integer = trees.id |
| 180 | + LEFT JOIN tree_species |
| 181 | + ON trees.species_id = tree_species.id |
| 182 | + LEFT JOIN region as country ON ST_WITHIN(trees.estimated_geometric_location, country.geom) |
| 183 | + and country.type_id in |
| 184 | + (SELECT id FROM region_type WHERE type = 'country') |
| 185 | + `; |
| 186 | + const object = await this.session.getDB().raw(sql); |
| 187 | + return object.rows; |
| 188 | + } |
| 189 | + |
| 190 | + async getByWallet( |
| 191 | + wallet_id: string, |
| 192 | + options: FilterOptions, |
| 193 | + totalCount = false, |
| 194 | + ) { |
| 195 | + const { limit, offset } = options; |
| 196 | + |
| 197 | + if (totalCount) { |
| 198 | + const totalSql = ` |
| 199 | + SELECT |
| 200 | + COUNT(*) |
| 201 | + FROM trees |
| 202 | + LEFT JOIN wallet.token ON token.capture_id::text = trees.uuid |
| 203 | + WHERE wallet.token.wallet_id = '${wallet_id}' |
| 204 | + `; |
| 205 | + const total = await this.session.getDB().raw(totalSql); |
| 206 | + return parseInt(total.rows[0].count.toString()); |
| 207 | + } |
| 208 | + |
| 209 | + const sql = ` |
| 210 | + SELECT |
| 211 | + trees.* |
| 212 | + FROM trees |
| 213 | + LEFT JOIN wallet.token ON token.capture_id::text = trees.uuid |
| 214 | + WHERE wallet.token.wallet_id = '${wallet_id}' |
| 215 | + LIMIT ${limit} |
| 216 | + OFFSET ${offset} |
| 217 | + `; |
| 218 | + const object = await this.session.getDB().raw(sql); |
| 219 | + return object.rows; |
| 220 | + } |
| 221 | +} |
0 commit comments