Skip to content

Commit f0a65dc

Browse files
committed
refactor(server): optimize query construction and db connection handling
1 parent d696255 commit f0a65dc

File tree

3 files changed

+186
-78
lines changed

3 files changed

+186
-78
lines changed

config/deno-kv.ts

Lines changed: 13 additions & 11 deletions
Original file line numberDiff line numberDiff line change
@@ -100,7 +100,7 @@ function cleanSpecialCharacters(input: string): string {
100100
// Remove emojis and other special characters
101101
const cleanedString = encodedString.replace(
102102
/[\u{1F600}-\u{1F64F}\u{1F300}-\u{1F5FF}\u{1F680}-\u{1F6FF}\u{1F1E0}-\u{1F1FF}\u{2600}-\u{26FF}\u{2700}-\u{27BF}]/gu,
103-
""
103+
"",
104104
);
105105

106106
// Remove extra whitespace
@@ -133,7 +133,7 @@ export async function listenQueue(kv: Deno.Kv) {
133133
Object.keys(msg.data.dataLayer.attributes).length < 5
134134
) {
135135
throw new Error(
136-
"Attributes are missing, undefined, or have fewer than 5 properties"
136+
"Attributes are missing, undefined, or have fewer than 5 properties",
137137
);
138138
}
139139

@@ -154,7 +154,7 @@ export async function listenQueue(kv: Deno.Kv) {
154154
typeof msg.data.dataLayer.location !== "object"
155155
) {
156156
throw new Error(
157-
"Location is missing, undefined, or not an object"
157+
"Location is missing, undefined, or not an object",
158158
);
159159
}
160160

@@ -164,7 +164,7 @@ export async function listenQueue(kv: Deno.Kv) {
164164
const images = msg.data.images as { src: string }[];
165165
const isCondominium =
166166
msg.data.dataLayer.attributes.attribute_set_name ===
167-
"Condominium";
167+
"Condominium";
168168
const isHouse =
169169
msg.data.dataLayer.attributes.attribute_set_name === "House";
170170
const isWarehouse =
@@ -185,8 +185,8 @@ export async function listenQueue(kv: Deno.Kv) {
185185
};
186186

187187
const price = msg.data.dataLayer?.attributes?.price;
188-
const priceFormatted =
189-
msg.data.dataLayer?.attributes?.price_formatted;
188+
const priceFormatted = msg.data.dataLayer?.attributes
189+
?.price_formatted;
190190

191191
await transaction.queryArray({
192192
args: [price, priceFormatted, listing.id],
@@ -216,8 +216,8 @@ export async function listenQueue(kv: Deno.Kv) {
216216
JSON.stringify(
217217
images.map((image) => image.src),
218218
null,
219-
2
220-
)
219+
2,
220+
),
221221
);
222222

223223
await transaction.commit();
@@ -273,8 +273,9 @@ export async function listenQueue(kv: Deno.Kv) {
273273
const productOwnerName = msg.data.dataLayer.product_owner_name;
274274
const location: Location = msg.data.dataLayer.location;
275275
const dataLayerAttributes = msg.data.dataLayer.attributes;
276-
const offerTypeId =
277-
dataLayerAttributes.offer_type === "Rent" ? 2 : 1;
276+
const offerTypeId = dataLayerAttributes.offer_type === "Rent"
277+
? 2
278+
: 1;
278279
const sellerIsTrusted = dataLayerAttributes?.seller_is_trusted;
279280
const locationData = await getLocation(transaction, {
280281
...location,
@@ -385,7 +386,8 @@ export async function listenQueue(kv: Deno.Kv) {
385386
offerTypeId,
386387
newProperty,
387388
],
388-
text: `INSERT INTO Listing (title, url, project_name, description, is_scraped, address, price_formatted, price, offer_type_id, property_id)
389+
text:
390+
`INSERT INTO Listing (title, url, project_name, description, is_scraped, address, price_formatted, price, offer_type_id, property_id)
389391
VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10) RETURNING id`,
390392
});
391393

config/postgres.ts

Lines changed: 8 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -1,12 +1,17 @@
1-
import { Pool } from "postgres";
1+
import { Pool, type QueryArguments } from "postgres";
22

33
const POOL_CONNECTIONS = 20;
44

55
export const dbPool = new Pool(Deno.env.get("DATABASE_URL"), POOL_CONNECTIONS);
66

7-
export async function runQuery(query: string) {
7+
export async function runQueryObject(query: string, args?: QueryArguments) {
88
using client = await dbPool.connect();
9-
return await client.queryObject(query);
9+
return await client.queryObject(query, args);
10+
}
11+
12+
export async function runQueryArray(query: string, args?: QueryArguments) {
13+
using client = await dbPool.connect();
14+
return await client.queryArray(query, args);
1015
}
1116

1217
export default dbPool;

server.ts

Lines changed: 165 additions & 64 deletions
Original file line numberDiff line numberDiff line change
@@ -1,76 +1,177 @@
11
import "jsr:@std/dotenv/load";
22
import { type Context, Hono } from "jsr:@hono/hono";
33

4-
import { runQuery } from "./config/postgres.ts";
4+
import { dbPool } from "./config/postgres.ts";
55
import { getKvInstance, listenQueue, sendMessage } from "./config/deno-kv.ts";
66

77
const app = new Hono();
88
const kv = await getKvInstance();
99

1010
app.get("/", async (c: Context) => {
11-
const postgres = await runQuery(`
12-
SELECT
13-
l.id AS listing_id,
14-
l.title,
15-
l.url,
16-
l.project_name,
17-
l.description,
18-
l.is_scraped,
19-
l.price,
20-
l.price_formatted,
21-
p.id AS property_id,
22-
p.user_id,
23-
p.floor_size,
24-
p.lot_size,
25-
p.building_size,
26-
p.ceiling_height,
27-
p.no_of_bedrooms,
28-
p.no_of_bathrooms,
29-
p.no_of_parking_spaces,
30-
p.longitude,
31-
p.latitude,
32-
p.year_built,
33-
p.primary_image_url,
34-
p.images,
35-
p.amenities,
36-
p.property_features,
37-
p.indoor_features,
38-
p.outdoor_features,
39-
p.ai_generated_description,
40-
p.ai_generated_basic_features,
41-
pt.type_name AS property_type_name,
42-
wt.type_name AS warehouse_type_name,
43-
l.address AS listing_address,
44-
rg.region AS listing_region_name,
45-
ct.city AS listing_city_name,
46-
ar.area AS listing_area_name,
47-
p.created_at AS property_created_at,
48-
p.updated_at AS property_updated_at,
49-
l.created_at AS listing_created_at,
50-
l.updated_at AS listing_updated_at,
51-
-- Price change log as an array ordered by latest changes
52-
(
53-
SELECT json_agg(
54-
json_build_object(
55-
'id', pcl.id,
56-
'old_price', pcl.old_price,
57-
'new_price', pcl.new_price,
58-
'change_timestamp', pcl.change_timestamp
59-
) ORDER BY pcl.change_timestamp DESC
60-
)
61-
FROM Price_Change_Log pcl
62-
WHERE pcl.listing_id = l.id
63-
) AS price_change_log
64-
FROM
65-
Listing l
66-
JOIN Property p ON l.property_id = p.id
67-
LEFT JOIN Property_Type pt ON p.property_type_id = pt.property_type_id
68-
LEFT JOIN Warehouse_Type wt ON p.warehouse_type_id = wt.warehouse_type_id
69-
LEFT JOIN Listing_Region rg ON p.listing_region_id = rg.id
70-
LEFT JOIN Listing_City ct ON p.listing_city_id = ct.id
71-
LEFT JOIN Listing_Area ar ON p.listing_area_id = ar.id
72-
ORDER BY l.id DESC LIMIT 50;
73-
`);
11+
using client = await dbPool.connect();
12+
const query = c.req.query() as unknown as {
13+
page?: string;
14+
page_size?: string;
15+
property_type_id?: string;
16+
listing_type_id?: string;
17+
search_longitude?: string;
18+
search_latitude?: string;
19+
bounding_box?: string;
20+
max_distance_km?: string;
21+
};
22+
23+
if (!query.page || !query.page_size) {
24+
query.page = "1";
25+
query.page_size = "10";
26+
}
27+
28+
if (!query.property_type_id) {
29+
query.property_type_id = "1";
30+
}
31+
32+
if (!query.listing_type_id) {
33+
query.listing_type_id = "1";
34+
}
35+
36+
const offset = (parseInt(query.page) - 1) * parseInt(query.page_size);
37+
38+
let boundingBoxCoords: number[] | null[] = [null, null, null, null];
39+
40+
if (query?.bounding_box) {
41+
boundingBoxCoords = query.bounding_box.split("::").map((coord) =>
42+
parseFloat(coord)
43+
);
44+
}
45+
46+
const searchLongitude = parseFloat(query?.search_longitude || "0");
47+
const searchLatitude = parseFloat(query?.search_latitude || "0");
48+
49+
// Initialize the SQL WHERE clause with base conditions
50+
let sqlWhereClause = `
51+
pt.property_type_id = $1
52+
AND lt.listing_type_id = $2
53+
`;
54+
55+
// Initialize the SQL parameters array with base parameters
56+
const sqlParams = [
57+
parseInt(query.property_type_id),
58+
parseInt(query.listing_type_id),
59+
parseInt(query.page_size),
60+
offset,
61+
];
62+
63+
// Initialize the parameter counter for dynamic parameter numbering
64+
let paramCounter = 5;
65+
66+
// Function to add a new condition to the WHERE clause
67+
// deno-lint-ignore no-explicit-any
68+
const addWhereCondition = (condition: string, ...params: any[]) => {
69+
sqlWhereClause += ` AND ${condition}`;
70+
sqlParams.push(...params);
71+
paramCounter += params.length;
72+
};
73+
74+
// Add bounding box condition if all coordinates are provided
75+
if (boundingBoxCoords.every((coord) => coord !== null)) {
76+
addWhereCondition(
77+
`
78+
p.latitude BETWEEN $${paramCounter} AND $${paramCounter + 1}
79+
AND p.longitude BETWEEN $${paramCounter + 2} AND $${paramCounter + 3}
80+
`,
81+
...boundingBoxCoords as number[],
82+
);
83+
}
84+
85+
// Add max distance condition if required parameters are provided
86+
if (query.max_distance_km && searchLongitude !== 0 && searchLatitude !== 0) {
87+
addWhereCondition(
88+
`
89+
ST_DWithin(p.geog, ST_SetSRID(ST_MakePoint($${paramCounter}, $${
90+
paramCounter + 1
91+
}), 4326)::geography, ${parseFloat(query.max_distance_km)} * 1000)
92+
`,
93+
searchLongitude,
94+
searchLatitude,
95+
);
96+
}
97+
98+
// Example of how to add a new condition in the future:
99+
// if (someNewCondition) {
100+
// addWhereCondition(`new_column = $${paramCounter}`, newValue);
101+
// }
102+
103+
console.log({ sqlWhereClause, sqlParams, nextParamCounter: paramCounter });
104+
105+
const postgres = await client.queryObject({
106+
args: sqlParams,
107+
text: `
108+
SELECT
109+
l.id AS listing_id,
110+
l.title,
111+
l.url,
112+
l.project_name,
113+
l.description,
114+
l.is_scraped,
115+
l.price,
116+
l.price_formatted,
117+
p.id AS property_id,
118+
p.user_id,
119+
p.floor_size,
120+
p.lot_size,
121+
p.building_size,
122+
p.ceiling_height,
123+
p.no_of_bedrooms,
124+
p.no_of_bathrooms,
125+
p.no_of_parking_spaces,
126+
p.longitude,
127+
p.latitude,
128+
p.year_built,
129+
p.primary_image_url,
130+
p.images,
131+
p.amenities,
132+
p.property_features,
133+
p.indoor_features,
134+
p.outdoor_features,
135+
p.ai_generated_description,
136+
p.ai_generated_basic_features,
137+
pt.type_name AS property_type_name,
138+
lt.type_name AS listing_type_name,
139+
wt.type_name AS warehouse_type_name,
140+
l.address AS listing_address,
141+
rg.region AS listing_region_name,
142+
ct.city AS listing_city_name,
143+
ar.area AS listing_area_name,
144+
p.created_at AS property_created_at,
145+
p.updated_at AS property_updated_at,
146+
l.created_at AS listing_created_at,
147+
l.updated_at AS listing_updated_at,
148+
-- Price change log as an array ordered by latest changes
149+
(
150+
SELECT json_agg(
151+
json_build_object(
152+
'id', pcl.id,
153+
'old_price', pcl.old_price,
154+
'new_price', pcl.new_price,
155+
'change_timestamp', pcl.change_timestamp
156+
) ORDER BY pcl.change_timestamp DESC
157+
)
158+
FROM Price_Change_Log pcl
159+
WHERE pcl.listing_id = l.id
160+
) AS price_change_log
161+
FROM
162+
Listing l
163+
JOIN Property p ON l.property_id = p.id
164+
LEFT JOIN Property_Type pt ON p.property_type_id = pt.property_type_id
165+
LEFT JOIN Listing_Type lt ON l.offer_type_id = lt.listing_type_id
166+
LEFT JOIN Warehouse_Type wt ON p.warehouse_type_id = wt.warehouse_type_id
167+
LEFT JOIN Listing_Region rg ON p.listing_region_id = rg.id
168+
LEFT JOIN Listing_City ct ON p.listing_city_id = ct.id
169+
LEFT JOIN Listing_Area ar ON p.listing_area_id = ar.id
170+
WHERE
171+
${sqlWhereClause}
172+
ORDER BY l.id DESC LIMIT $3 OFFSET $4;
173+
`,
174+
});
74175
return c.json(postgres.rows);
75176
});
76177

0 commit comments

Comments
 (0)