13 KiB
IPN Callback Integration Guide
Overview
This document describes the race condition prevention system implemented for the 420Deals.ch collective drop platform. The system uses a 10-minute reservation mechanism via the pending_orders table to prevent overselling when multiple buyers attempt to purchase the last available units simultaneously.
Database Schema
pending_orders Table
CREATE TABLE `pending_orders` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`payment_id` varchar(255) NOT NULL, -- NOWPayments invoice/payment ID
`order_id` varchar(255) NOT NULL, -- Internal order ID (format: SALE-{timestamp}-{drop_id}-{buyer_id})
`drop_id` int(11) NOT NULL, -- Foreign key to drops table
`buyer_id` int(11) NOT NULL, -- Foreign key to buyers table
`size` int(11) NOT NULL, -- Quantity in grams
`price_amount` decimal(10,2) NOT NULL, -- Price amount
`price_currency` varchar(10) NOT NULL DEFAULT 'chf',
`created_at` datetime NOT NULL DEFAULT current_timestamp(),
`expires_at` datetime NOT NULL, -- Expiration time (10 minutes from creation)
PRIMARY KEY (`id`),
UNIQUE KEY `payment_id` (`payment_id`),
UNIQUE KEY `order_id` (`order_id`),
KEY `drop_id` (`drop_id`),
KEY `buyer_id` (`buyer_id`),
KEY `idx_expires_at` (`expires_at`), -- Index for cleanup queries
FOREIGN KEY (`drop_id`) REFERENCES `drops` (`id`) ON DELETE CASCADE,
FOREIGN KEY (`buyer_id`) REFERENCES `buyers` (`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
sales Table
CREATE TABLE `sales` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`drop_id` int(11) NOT NULL,
`buyer_id` int(11) NOT NULL,
`size` int(11) NOT NULL DEFAULT 1, -- Quantity in grams
`payment_id` text NOT NULL DEFAULT '', -- NOWPayments payment ID (matches pending_orders.payment_id)
`created_at` datetime NOT NULL DEFAULT current_timestamp(),
PRIMARY KEY (`id`),
KEY `drop_id` (`drop_id`),
KEY `buyer_id` (`buyer_id`),
FOREIGN KEY (`drop_id`) REFERENCES `drops` (`id`) ON DELETE CASCADE,
FOREIGN KEY (`buyer_id`) REFERENCES `buyers` (`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
How the System Works
1. Purchase Flow
When a buyer initiates a purchase:
- Inventory Check: System checks available inventory =
drop.size - (sales.total + non_expired_pending_orders.total) - Reservation: If inventory available, creates
pending_orderwith:expires_at= NOW() + 10 minutes- Inventory is now "on hold"
- Invoice Creation: Creates NOWPayments invoice with
invoice_timeout: 600(10 minutes) - Transaction: All of the above happens atomically in a database transaction
2. Inventory Calculation
Available Inventory = drop.size - (SUM(sales.size) + SUM(pending_orders.size WHERE expires_at > NOW()))
sales.size: Confirmed purchases (permanent)pending_orders.size: Temporary reservations (expire after 10 minutes)
3. Expiration
- Pending orders expire 10 minutes after creation (
expires_at < NOW()) - Expired orders should be cleaned up periodically (recommended: every 1-2 minutes)
- Cleanup endpoint:
POST /api/payments/cleanup-expired - Expired orders are automatically excluded from inventory calculations
IPN Callback Handling
NOWPayments IPN Callback Format
The system expects IPN callbacks with the following structure:
{
"payment_id": "string", // NOWPayments payment/invoice ID
"invoice_id": "string", // Alternative field name (used if payment_id not present)
"order_id": "string", // Internal order ID (format: SALE-{timestamp}-{drop_id}-{buyer_id})
"payment_status": "string", // Status: waiting, confirming, confirmed, finished, failed, expired, etc.
"pay_amount": "number",
"pay_currency": "string",
"price_amount": "number",
"price_currency": "string"
}
IPN Callback Processing Logic
Your IPN callback handler should follow this flow:
Step 1: Find Pending Order
SELECT * FROM pending_orders
WHERE payment_id = ? OR payment_id = ?
-- Try both payment_id and invoice_id from callback
Important: The system uses payment_id OR invoice_id to find pending orders. Check both fields.
Step 2: Check Expiration
-- Verify order hasn't expired
SELECT * FROM pending_orders
WHERE id = ? AND expires_at > NOW()
Action if expired:
- Delete the pending order
- Return error response (don't create sale)
- Log the expiration
Step 3: Validate Payment Status
Process based on payment_status:
finishedorconfirmed: Payment successful → proceed to Step 4failedorexpired: Payment failed → delete pending order, return successwaiting,confirming: Payment in progress → return success, wait for final status
Step 4: Final Inventory Check (Before Creating Sale)
-- Get drop details
SELECT * FROM drops WHERE id = ?
-- Calculate current inventory
SELECT COALESCE(SUM(size), 0) as total_sales
FROM sales WHERE drop_id = ?
-- Calculate other pending orders (excluding current one)
SELECT COALESCE(SUM(size), 0) as total_pending
FROM pending_orders
WHERE drop_id = ?
AND id != ?
AND expires_at > NOW()
-- Check availability
-- Available = drop.size - (total_sales + total_pending)
-- If pending_order.size > Available: REJECT
Important: Always check inventory again before creating the sale, as other buyers may have reserved inventory in the meantime.
Step 5: Create Sale Record
If inventory is available:
-- Create sale (include buyer_data_id for delivery information)
INSERT INTO sales (drop_id, buyer_id, buyer_data_id, size, payment_id)
VALUES (?, ?, ?, ?, ?)
-- Delete pending order
DELETE FROM pending_orders WHERE id = ?
Important:
- Use the same
payment_idfrom pending_order for the sale record - Delete the pending order after creating the sale
- This should be done in a transaction to ensure atomicity
Step 6: Handle Idempotency
Before creating a sale, check if it already exists:
SELECT * FROM sales WHERE payment_id = ?
If sale exists, return success (idempotent operation).
Example IPN Callback Handler (Pseudocode)
async function handleIPNCallback(callbackData) {
const { payment_id, invoice_id, order_id, payment_status } = callbackData;
// Step 1: Find pending order
const paymentIdToFind = invoice_id || payment_id;
const pendingOrder = await db.query(
'SELECT * FROM pending_orders WHERE payment_id = ?',
[paymentIdToFind]
);
if (!pendingOrder) {
// Check if sale already exists (idempotency)
const existingSale = await db.query(
'SELECT * FROM sales WHERE payment_id = ?',
[paymentIdToFind]
);
if (existingSale) {
return { status: 'ok' }; // Already processed
}
return { error: 'Pending order not found' };
}
// Step 2: Check expiration
if (new Date(pendingOrder.expires_at) < new Date()) {
await db.query('DELETE FROM pending_orders WHERE id = ?', [pendingOrder.id]);
return { error: 'Order expired' };
}
// Step 3: Process payment status
if (payment_status === 'finished' || payment_status === 'confirmed') {
// Step 4: Final inventory check
const drop = await db.query('SELECT * FROM drops WHERE id = ?', [pendingOrder.drop_id]);
const sales = await db.query(
'SELECT COALESCE(SUM(size), 0) as total FROM sales WHERE drop_id = ?',
[pendingOrder.drop_id]
);
const otherPending = await db.query(
'SELECT COALESCE(SUM(size), 0) as total FROM pending_orders WHERE drop_id = ? AND id != ? AND expires_at > NOW()',
[pendingOrder.drop_id, pendingOrder.id]
);
const totalReserved = sales.total + otherPending.total;
const available = drop.size - totalReserved;
if (pendingOrder.size > available) {
await db.query('DELETE FROM pending_orders WHERE id = ?', [pendingOrder.id]);
return { error: 'Inventory no longer available' };
}
// Step 5: Create sale (include buyer_data_id for delivery information)
await db.transaction(async (tx) => {
await tx.query(
'INSERT INTO sales (drop_id, buyer_id, buyer_data_id, size, payment_id) VALUES (?, ?, ?, ?, ?)',
[pendingOrder.drop_id, pendingOrder.buyer_id, pendingOrder.buyer_data_id, pendingOrder.size, pendingOrder.payment_id]
);
await tx.query('DELETE FROM pending_orders WHERE id = ?', [pendingOrder.id]);
});
return { status: 'ok' };
} else if (payment_status === 'failed' || payment_status === 'expired') {
await db.query('DELETE FROM pending_orders WHERE id = ?', [pendingOrder.id]);
return { status: 'ok' };
}
return { status: 'ok' }; // Payment still in progress
}
Important Considerations
1. Database Transactions
- Always use transactions when creating sales and deleting pending orders
- This ensures atomicity and prevents race conditions
2. Expiration Handling
- Expired pending orders should be excluded from inventory calculations
- Clean up expired orders periodically (every 1-2 minutes recommended)
- The main application has a cleanup endpoint:
POST /api/payments/cleanup-expired
3. Unit Conversion
- All
sizevalues insalesandpending_ordersare stored in grams drops.sizeanddrops.unitmay be in different units (g or kg)- When calculating inventory, convert to the drop's unit:
if (drop.unit === 'kg') { sizeInDropUnit = sizeInGrams / 1000; }
4. Idempotency
- IPN callbacks may be sent multiple times
- Always check if a sale already exists before creating a new one
- Use
payment_idto check for existing sales
5. Error Handling
- Always return HTTP 200 to NOWPayments, even on errors
- Log errors for debugging
- Don't retry failed operations indefinitely
6. Inventory Availability
- Inventory is calculated as:
drop.size - (sales + non_expired_pending_orders) - Always re-check inventory before creating a sale
- Other buyers may have reserved inventory between payment initiation and confirmation
API Endpoints Reference
Cleanup Expired Orders
POST /api/payments/cleanup-expired
Authorization: Bearer {CLEANUP_API_TOKEN} (optional)
Response:
{
"message": "Cleaned up X expired pending orders",
"cleaned": 5,
"total": 5
}
Check Expired Orders Count
GET /api/payments/cleanup-expired
Response:
{
"expired_orders_count": 3,
"message": "There are 3 expired pending orders that need cleanup"
}
Testing Checklist
When implementing your IPN callback handler, test:
- ✅ Payment success → Sale created, pending order deleted
- ✅ Payment failure → Pending order deleted, no sale created
- ✅ Payment expiration → Pending order deleted, no sale created
- ✅ Expired pending order → Rejected, no sale created
- ✅ Insufficient inventory → Pending order deleted, no sale created
- ✅ Duplicate IPN callbacks → Idempotent (sale not created twice)
- ✅ Race condition → Only one sale created when multiple payments complete simultaneously
Database Queries Reference
Find Pending Order by Payment ID
SELECT * FROM pending_orders
WHERE payment_id = ? OR payment_id = ?
Check if Pending Order is Expired
SELECT * FROM pending_orders
WHERE id = ? AND expires_at > NOW()
Calculate Available Inventory
-- Sales
SELECT COALESCE(SUM(size), 0) as total_sales
FROM sales WHERE drop_id = ?
-- Non-expired pending orders
SELECT COALESCE(SUM(size), 0) as total_pending
FROM pending_orders
WHERE drop_id = ? AND expires_at > NOW()
-- Available = drop.size - (total_sales + total_pending)
Create Sale and Delete Pending Order (Transaction)
START TRANSACTION;
INSERT INTO sales (drop_id, buyer_id, buyer_data_id, size, payment_id)
VALUES (?, ?, ?, ?, ?);
DELETE FROM pending_orders WHERE id = ?;
COMMIT;
Check for Existing Sale (Idempotency)
SELECT * FROM sales WHERE payment_id = ?
Environment Variables
The main application uses these environment variables (for reference):
IPN_CALLBACK_URL: URL where NOWPayments sends IPN callbacksCLEANUP_API_TOKEN: (Optional) Token for cleanup endpoint authenticationNOWPAYMENTS_API_KEY: NOWPayments API keyNOWPAYMENTS_TESTNET: Set to 'true' for sandbox environment
Support
For questions or issues with the IPN callback integration, refer to:
- Database schema:
cbd420.sql - Race condition fix documentation:
RACE_CONDITION_FIX.md
Note: The main application does not include an IPN callback handler. All IPN callbacks must be handled by your external service using the logic described in this document.