Add HTS lookup page

This commit is contained in:
2025-11-25 12:31:59 -05:00
parent ad5b797ce6
commit 9be0f34f07
8 changed files with 530 additions and 1 deletions

View File

@@ -0,0 +1,170 @@
const express = require('express');
const router = express.Router();
// GET /api/hts-lookup?search=term
// Finds matching products and groups them by harmonized tariff code
router.get('/', async (req, res) => {
const searchTerm = typeof req.query.search === 'string' ? req.query.search.trim() : '';
if (!searchTerm) {
return res.status(400).json({ error: 'Search term is required' });
}
try {
const pool = req.app.locals.pool;
const likeTerm = `%${searchTerm}%`;
const { rows } = await pool.query(
`
WITH matched_products AS (
SELECT
pid,
title,
sku,
barcode,
brand,
vendor,
harmonized_tariff_code,
NULLIF(
LOWER(
REGEXP_REPLACE(
COALESCE(NULLIF(TRIM(harmonized_tariff_code), ''), ''),
'[^0-9A-Za-z]',
'',
'g'
)
),
''
) AS normalized_code
FROM products
WHERE visible = TRUE
AND (
title ILIKE $1
OR sku ILIKE $1
OR barcode ILIKE $1
OR vendor ILIKE $1
OR brand ILIKE $1
OR vendor_reference ILIKE $1
OR harmonized_tariff_code ILIKE $1
)
),
grouped AS (
SELECT
COALESCE(NULLIF(TRIM(harmonized_tariff_code), ''), 'Unspecified') AS harmonized_tariff_code,
normalized_code,
COUNT(*)::INT AS product_count,
json_agg(
json_build_object(
'pid', pid,
'title', title,
'sku', sku,
'barcode', barcode,
'brand', brand,
'vendor', vendor
)
ORDER BY title
) AS products
FROM matched_products
GROUP BY
COALESCE(NULLIF(TRIM(harmonized_tariff_code), ''), 'Unspecified'),
normalized_code
),
hts_lookup AS (
SELECT
h."HTS Number" AS hts_number,
h."Indent" AS indent,
h."Description" AS description,
h."Unit of Quantity" AS unit_of_quantity,
h."General Rate of Duty" AS general_rate_of_duty,
h."Special Rate of Duty" AS special_rate_of_duty,
h."Column 2 Rate of Duty" AS column2_rate_of_duty,
h."Quota Quantity" AS quota_quantity,
h."Additional Duties" AS additional_duties,
NULLIF(
LOWER(
REGEXP_REPLACE(
COALESCE(h."HTS Number", ''),
'[^0-9A-Za-z]',
'',
'g'
)
),
''
) AS normalized_hts_number
FROM htsdata h
)
SELECT
g.harmonized_tariff_code,
g.product_count,
g.products,
hts.hts_details
FROM grouped g
LEFT JOIN LATERAL (
SELECT json_agg(
json_build_object(
'hts_number', h.hts_number,
'indent', h.indent,
'description', h.description,
'unit_of_quantity', h.unit_of_quantity,
'general_rate_of_duty', h.general_rate_of_duty,
'special_rate_of_duty', h.special_rate_of_duty,
'column2_rate_of_duty', h.column2_rate_of_duty,
'quota_quantity', h.quota_quantity,
'additional_duties', h.additional_duties
)
ORDER BY LENGTH(COALESCE(h.normalized_hts_number, '')) ASC NULLS LAST,
NULLIF(h.indent, '')::INT NULLS LAST
) AS hts_details
FROM hts_lookup h
WHERE COALESCE(g.normalized_code, '') <> ''
AND COALESCE(h.normalized_hts_number, '') <> ''
AND (
g.normalized_code LIKE h.normalized_hts_number || '%'
OR h.normalized_hts_number LIKE g.normalized_code || '%'
)
) hts ON TRUE
ORDER BY g.product_count DESC, g.harmonized_tariff_code ASC
`,
[likeTerm]
);
const totalMatches = rows.reduce((sum, row) => sum + (parseInt(row.product_count, 10) || 0), 0);
res.json({
search: searchTerm,
total: totalMatches,
results: rows.map(row => ({
harmonized_tariff_code: row.harmonized_tariff_code,
product_count: parseInt(row.product_count, 10) || 0,
hts_details: Array.isArray(row.hts_details)
? row.hts_details.map(detail => ({
hts_number: detail.hts_number,
indent: detail.indent,
description: detail.description,
unit_of_quantity: detail.unit_of_quantity,
general_rate_of_duty: detail.general_rate_of_duty,
special_rate_of_duty: detail.special_rate_of_duty,
column2_rate_of_duty: detail.column2_rate_of_duty,
quota_quantity: detail.quota_quantity,
additional_duties: detail.additional_duties
}))
: [],
products: Array.isArray(row.products)
? row.products.map(product => ({
pid: product.pid,
title: product.title,
sku: product.sku,
barcode: product.barcode,
brand: product.brand,
vendor: product.vendor
}))
: []
}))
});
} catch (error) {
console.error('Error performing HTS lookup:', error);
res.status(500).json({ error: 'Failed to lookup HTS codes' });
}
});
module.exports = router;

View File

@@ -21,6 +21,7 @@ const reusableImagesRouter = require('./routes/reusable-images');
const categoriesAggregateRouter = require('./routes/categoriesAggregate');
const vendorsAggregateRouter = require('./routes/vendorsAggregate');
const brandsAggregateRouter = require('./routes/brandsAggregate');
const htsLookupRouter = require('./routes/hts-lookup');
// Get the absolute path to the .env file
const envPath = '/var/www/html/inventory/.env';
@@ -126,6 +127,7 @@ async function startServer() {
app.use('/api/templates', templatesRouter);
app.use('/api/ai-prompts', aiPromptsRouter);
app.use('/api/reusable-images', reusableImagesRouter);
app.use('/api/hts-lookup', htsLookupRouter);
// Basic health check route
app.get('/health', (req, res) => {