Wednesday, August 27, 2025

CSV to Search Engine: How to Build a Powerful Tariff Finder with PHP and SQLite

Navigating international trade often comes down to one notoriously complex document: the Harmonized Tariff Schedule (HTS). For developers and e-commerce merchants, deciphering this data—especially from a raw CSV file—to calculate duties is a significant technical hurdle. When new tariffs are imposed, the need for a quick, accurate, and user-friendly lookup tool becomes critical. A CSV can be found Here.

A naive approach might involve a simple script that scans the CSV file for a keyword on every search. This method is not only slow but fundamentally flawed. The official HTS data is hierarchical; a product's full description is spread across multiple rows, identified only by an "Indent" level. Searching for "Nile perch," for example, gives you a row that lacks the crucial context of its parent categories, like "Other fish."

In this guide, we'll walk through a professional, scalable solution. We will build a fast, modern web application that transforms the official HTS CSV into a powerful search engine using PHP, SQLite, and vanilla JavaScript.

The Architecture: A Scalable Three-Tier Approach

To build a system that is both fast and accurate, we will separate our concerns into three distinct components:

The Importer (import.php): A one-time processing script that reads the complex, indented CSV, intelligently builds full product descriptions, and stores the clean data in a structured SQLite database.

The API (api.php): A lightweight backend endpoint that queries the pre-processed database and returns results as JSON. This decouples our data logic from the user interface.

The Frontend (index.html): A clean, responsive user interface that communicates with the API to provide a seamless search experience for the end-user.

This database-driven model ensures that searches are performed on optimized, structured data, making the application lightning-fast, regardless of the CSV's size.

Step 1: The Brains – Processing the CSV into a SQLite Database

This is the most crucial step. We create a PHP script, import.php, that acts as our one-time data processor. Its job is to read the official HTS CSV, understand the hierarchy defined by the Indent column, and construct a complete, human-readable description for every single tariff item.

The script maintains a "stack" of descriptions. As it iterates through the rows, it uses the indent level to add or replace descriptions in the stack, then joins them to form a complete trail (e.g., "Other fish - Other - Nile perch"). This full description is then inserted into a clean SQLite table alongside its HTS number and duty rates.

Here is the complete code for the importer: [import.php]

<?php

ini_set('display_errors', 1);

error_reporting(E_ALL);

set_time_limit(300); // Allow script to run for 5 minutes

// Configuration: Point to your source CSV and the desired database file

$csvFile = 'hts_2025_revision_19_csv-Copy.csv';

$dbFile = 'tariffs.db';

if (!file_exists($csvFile)) {

    die("Error: CSV file not found. Ensure it's in the same directory.");

}

try {

    // Connect to SQLite, creating the database file if it doesn't exist

    $pdo = new PDO('sqlite:' . $dbFile);

    $pdo->setAttribute(PDO::ATTR_ERRMODE, PDO::ERRMODE_EXCEPTION);


    // Re-create the table each time to ensure fresh data

    $pdo->exec("DROP TABLE IF EXISTS tariffs");

    $pdo->exec("CREATE TABLE tariffs (

        id INTEGER PRIMARY KEY AUTOINCREMENT,

        hts_number TEXT,

        full_description TEXT,

        general_rate TEXT,

        special_rate TEXT,

        column_2_rate TEXT

    )");

    echo "Database and table created successfully.<br>";

    $handle = fopen($csvFile, 'r');

    fgetcsv($handle); // Skip header row


    $pdo->beginTransaction();

    $description_stack = [];

    $rowCount = 0;

    // The core processing logic

    while (($row = fgetcsv($handle)) !== FALSE) {

        list($htsNumber, $indent, $description, $unit, $generalRate, $specialRate, $col2Rate) = array_pad($row, 7, '');

        $indent = (int)$indent;

        // Build the hierarchical description

        $description_stack[$indent] = rtrim(trim($description), ':');

        $full_description_parts = array_slice($description_stack, 0, $indent + 1);

        $fullDescription = implode(' - ', array_filter($full_description_parts));


        // Insert only the final, categorized items (those with an HTS number)

        if (!empty(trim($htsNumber))) {

            $stmt = $pdo->prepare(

                "INSERT INTO tariffs (hts_number, full_description, general_rate, special_rate, column_2_rate) 

                 VALUES (?, ?, ?, ?, ?)"

            );

            $stmt->execute([trim($htsNumber), $fullDescription, trim($generalRate), trim($specialRate), trim($col2Rate)]);

            $rowCount++;

        }

    }

    $pdo->commit();

    fclose($handle);

    echo "<h1>Success!</h1><p>Imported <strong>$rowCount records</strong> into 'tariffs.db'.</p>";

} catch (Exception $e) {

    if ($pdo->inTransaction()) {

        $pdo->rollBack();

    }

    die("An error occurred: " . $e->getMessage());

}

?>

Step 2: The Engine – Building a Fast Search API

With our data neatly organized, we need an efficient way to query it. The api.php script serves this purpose. It accepts a search term, runs a simple but powerful LIKE query against the full_description column in our SQLite database, and returns the findings as a JSON object. This approach is highly scalable, as database queries are significantly faster than file-system operations.

api.php

<?php

header('Content-Type: application/json');

$dbFile = 'tariffs.db';

$response = ['error' => 'An unknown error occurred.'];

if (!file_exists($dbFile)) {

    echo json_encode(['error' => 'Database not found. Please run import.php first.']);

    exit;

}

$searchTerm = isset($_GET['query']) ? trim($_GET['query']) : '';

if (strlen($searchTerm) < 3) {

    echo json_encode(['error' => 'Search term must be at least 3 characters.']);

    exit;

}

try {

    $pdo = new PDO('sqlite:' . $dbFile);

    $pdo->setAttribute(PDO::ATTR_ERRMODE, PDO::ERRMODE_EXCEPTION);

    // Prepare and execute the search query

    $stmt = $pdo->prepare(

        "SELECT hts_number, full_description, general_rate, special_rate, column_2_rate 

         FROM tariffs 

         WHERE full_description LIKE ?

         LIMIT 50" // Limit results for performance

    );

    $stmt->execute(['%' . $searchTerm . '%']);

    $results = $stmt->fetchAll(PDO::FETCH_ASSOC);

    echo json_encode($results);

} catch (Exception $e) {

    echo json_encode(['error' => 'Database query failed: ' . $e->getMessage()]);

}

?>

Step 3: The Interface – A User-Friendly Frontend

The final piece is the index.html file, which provides the user experience. It contains a search box that uses modern JavaScript (fetch API) to communicate with our api.php backend asynchronously. To enhance usability, a "debounce" mechanism is implemented to prevent sending a request on every keystroke, instead waiting until the user has paused typing.

The interface intelligently handles the results: if only one match is found, it displays the full details directly. If multiple matches are found, it presents them as a list of choices, allowing the user to select the correct one.

index.html

<!DOCTYPE html>

<html lang="en">

<head>

    <meta charset="UTF-8">

    <meta name="viewport" content="width=device-width, initial-scale=1.0">

    <title>Professional Tariff Finder</title>

    <style>

        :root {

            --primary-color: #005A9C; --secondary-color: #f0f6fa; --border-color: #d0d7de;

            --text-color: #24292f; --highlight-bg: #fffbdd;

        }

        body { font-family: sans-serif; line-height: 1.6; color: var(--text-color); max-width: 900px; margin: 20px auto; padding: 20px; }

        h1 { color: var(--primary-color); border-bottom: 2px solid var(--primary-color); padding-bottom: 10px; }

        #searchBox { width: 100%; padding: 15px; font-size: 18px; border: 1px solid var(--border-color); border-radius: 6px; box-sizing: border-box; }

        #status { margin-top: 15px; color: #666; min-height: 20px; }

        .result-item { border: 1px solid var(--border-color); border-radius: 6px; padding: 15px; margin-bottom: 10px; }

        .result-item.choice:hover { background-color: var(--secondary-color); cursor: pointer; }

        .result-item h3 { margin: 0 0 10px 0; color: var(--primary-color); }

        .result-item .rate { font-weight: bold; color: #c9372c; }

        #back-button { display: none; margin-bottom: 15px; padding: 8px 15px; border: 1px solid var(--border-color); border-radius: 6px; cursor: pointer; }

    </style>

</head>

<body>

    <h1>U.S. Harmonized Tariff Schedule Search</h1>

    <p>Enter a product description (e.g., "ceramic cup", "nile perch") to find probable tariff categories.</p>

    <input type="text" id="searchBox" placeholder="Start typing a product name..." autocomplete="off">

    <div id="status"></div>

    <button id="back-button">&laquo; Back to Search Results</button>

    <div id="results"></div>


<script>

    const searchBox = document.getElementById('searchBox');

    const resultsContainer = document.getElementById('results');

    const statusContainer = document.getElementById('status');

    const backButton = document.getElementById('back-button');

    let debounceTimer, lastResults = [];

    searchBox.addEventListener('input', () => {

        clearTimeout(debounceTimer);

        debounceTimer = setTimeout(performSearch, 300);

    });

   backButton.addEventListener('click', () => displayResults(lastResults, false));

    function performSearch() {

        const query = searchBox.value.trim();

        if (query.length < 3) {

            resultsContainer.innerHTML = '';

            statusContainer.textContent = 'Please enter at least 3 characters.';

            return;

        }

        statusContainer.textContent = 'Searching...';

        fetch(`api.php?query=${encodeURIComponent(query)}`)

            .then(res => res.json()).then(data => {

                if (data.error) throw new Error(data.error);

                lastResults = data;

                displayResults(data);

            }).catch(err => {

                statusContainer.textContent = '';

                resultsContainer.innerHTML = `<div class="result-item"><strong>Error:</strong> ${err.message}</div>`;

            });

    }


    function displayResults(data, isNewSearch = true) {

        resultsContainer.innerHTML = '';

        backButton.style.display = 'none';

        if (isNewSearch) statusContainer.textContent = `${data.length} potential match(es) found.`;

        if (data.length === 1) return displaySingleResult(data[0]);

        data.forEach(item => {

            const div = document.createElement('div');

            div.className = 'result-item choice';

            div.innerHTML = `<h3>${item.hts_number}</h3><p>${item.full_description}</p><p><strong>General Rate:</strong> <span class="rate">${item.general_rate || 'N/A'}</span></p>`;

            div.addEventListener('click', () => displaySingleResult(item));

            resultsContainer.appendChild(div);

        });

    }

    function displaySingleResult(item) {

        statusContainer.textContent = 'Showing details for your selection.';

        if (lastResults.length > 1) backButton.style.display = 'block';

        resultsContainer.innerHTML = `

            <div class="result-item">

                <h3>${item.hts_number}</h3>

                <p><strong>Full Description:</strong> ${item.full_description}</p>

                <p><strong>General Rate of Duty:</strong> <span class="rate">${item.general_rate || 'N/A'}</span></p>

                <p><strong>Special Rate of Duty:</strong> <span>${item.special_rate || 'N/A'}</span></p>

                <p><strong>Column 2 Rate of Duty:</strong> <span>${item.column_2_rate || 'N/A'}</span></p>

            </div>`;

    }

</script>

</body>

</html>


Launching The Tariff Finder

Setup: Place the three files (import.php, api.php, index.html) and your source hts .. csv file in a directory on a web server with PHP and the SQLite extension enabled.

Import Data: Run the importer script once by navigating to your-domain.com/import.php in your browser. You should see a success message. This will create the tariffs.db file.

Launch: Open index.html in your browser. You can now start searching.


Conclusion and Next Steps :: 

By investing a little time in pre-processing the data, we have transformed an unusable CSV into a high-performance search application. This professional approach not only provides a superior user experience but also creates a robust foundation that can be easily extended.

From here, you could enhance the system further by:

Implementing SQLite's Full-Text Search (FTS5) for more advanced, weighted searching.

Adding a frontend framework like Vue or React for a more complex UI.

Creating a cron job to run the import.php script periodically to keep the tariff data up-to-date automatically.

This solution empowers developers to tackle complex data challenges with elegant, efficient, and scalable code, turning a business problem into a powerful internal tool. 

No comments: