feat: Implement loan management features including fetching, creating, and deleting loans
- Added database functions for managing loans: getLoans, getUserLoans, deleteLoan, and createLoan. - Updated frontend to include new Form4 for displaying user loans and handling loan deletions. - Replaced Form3 with Form4 in App component. - Enhanced Form1 to set borrowing dates and fetch available items. - Improved Form2 to display borrowable items and allow selection for loans. - Introduced utility functions for handling loan creation and deletion in userHandler. - Added event listeners for local storage updates to keep UI in sync. - Updated fetchData utility to retrieve loans and user loans from the backend.
This commit is contained in:
@@ -1,5 +1,13 @@
|
||||
import express from "express";
|
||||
import { loginFunc, getItemsFromDatabase } from "../services/database.js";
|
||||
import {
|
||||
loginFunc,
|
||||
getItemsFromDatabase,
|
||||
getLoansFromDatabase,
|
||||
getUserLoansFromDatabase,
|
||||
deleteLoanFromDatabase,
|
||||
getBorrowableItemsFromDatabase,
|
||||
createLoanInDatabase,
|
||||
} from "../services/database.js";
|
||||
import { authenticate, generateToken } from "../services/tokenService.js";
|
||||
const router = express.Router();
|
||||
|
||||
@@ -27,4 +35,114 @@ router.get("/items", authenticate, async (req, res) => {
|
||||
}
|
||||
});
|
||||
|
||||
router.get("/loans", authenticate, async (req, res) => {
|
||||
const result = await getLoansFromDatabase();
|
||||
if (result.success) {
|
||||
res.status(200).json(result.data);
|
||||
} else {
|
||||
res.status(500).json({ message: "Failed to fetch loans" });
|
||||
}
|
||||
});
|
||||
|
||||
router.get("/userLoans", authenticate, async (req, res) => {
|
||||
const result = await getUserLoansFromDatabase(req.user.username);
|
||||
if (result.success) {
|
||||
res.status(200).json(result.data);
|
||||
} else {
|
||||
res.status(500).json({ message: "Failed to fetch user loans" });
|
||||
}
|
||||
});
|
||||
|
||||
router.delete("/deleteLoan/:id", authenticate, async (req, res) => {
|
||||
const loanId = req.params.id;
|
||||
const result = await deleteLoanFromDatabase(loanId);
|
||||
if (result.success) {
|
||||
res.status(200).json({ message: "Loan deleted successfully" });
|
||||
} else {
|
||||
res.status(500).json({ message: "Failed to delete loan" });
|
||||
}
|
||||
});
|
||||
|
||||
router.post("/borrowableItems", authenticate, async (req, res) => {
|
||||
const { startDate, endDate } = req.body || {};
|
||||
if (!startDate || !endDate) {
|
||||
return res
|
||||
.status(400)
|
||||
.json({ message: "startDate and endDate are required" });
|
||||
}
|
||||
|
||||
const result = await getBorrowableItemsFromDatabase(
|
||||
startDate,
|
||||
endDate,
|
||||
req.user.role
|
||||
);
|
||||
if (result.success) {
|
||||
// return the array directly for consistency with /items
|
||||
return res.status(200).json(result.data);
|
||||
} else {
|
||||
return res
|
||||
.status(500)
|
||||
.json({ message: "Failed to fetch borrowable items" });
|
||||
}
|
||||
});
|
||||
|
||||
router.post("/createLoan", authenticate, async (req, res) => {
|
||||
try {
|
||||
const { items, startDate, endDate } = req.body || {};
|
||||
|
||||
if (!Array.isArray(items) || items.length === 0) {
|
||||
return res.status(400).json({ message: "Items array is required" });
|
||||
}
|
||||
|
||||
// If dates are not provided, default to now .. +7 days
|
||||
const start =
|
||||
startDate ?? new Date().toISOString().slice(0, 19).replace("T", " ");
|
||||
const end =
|
||||
endDate ??
|
||||
new Date(Date.now() + 7 * 24 * 60 * 60 * 1000)
|
||||
.toISOString()
|
||||
.slice(0, 19)
|
||||
.replace("T", " ");
|
||||
|
||||
// Coerce item IDs to numbers and filter invalids
|
||||
const itemIds = items
|
||||
.map((v) => Number(v))
|
||||
.filter((n) => Number.isFinite(n));
|
||||
|
||||
if (itemIds.length === 0) {
|
||||
return res.status(400).json({ message: "No valid item IDs provided" });
|
||||
}
|
||||
|
||||
const result = await createLoanInDatabase(
|
||||
req.user.username,
|
||||
start,
|
||||
end,
|
||||
itemIds
|
||||
);
|
||||
|
||||
if (result.success) {
|
||||
return res.status(201).json({
|
||||
message: "Loan created successfully",
|
||||
loanId: result.data.id,
|
||||
loanCode: result.data.loan_code,
|
||||
});
|
||||
}
|
||||
|
||||
if (result.code === "CONFLICT") {
|
||||
return res
|
||||
.status(409)
|
||||
.json({ message: "Items not available in the selected period" });
|
||||
}
|
||||
|
||||
if (result.code === "BAD_REQUEST") {
|
||||
return res.status(400).json({ message: result.message });
|
||||
}
|
||||
|
||||
return res.status(500).json({ message: "Failed to create loan" });
|
||||
} catch (err) {
|
||||
console.error("createLoan error:", err);
|
||||
return res.status(500).json({ message: "Failed to create loan" });
|
||||
}
|
||||
});
|
||||
|
||||
export default router;
|
||||
|
@@ -20,6 +20,7 @@ CREATE TABLE `loans` (
|
||||
`returned_date` timestamp NULL DEFAULT NULL,
|
||||
`created_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
`loaned_items_id` json NOT NULL DEFAULT ('[]'),
|
||||
`loaned_items_name` json NOT NULL DEFAULT ('[]'),
|
||||
PRIMARY KEY (`id`),
|
||||
UNIQUE KEY `loan_code` (`loan_code`)
|
||||
);
|
||||
@@ -27,7 +28,7 @@ CREATE TABLE `loans` (
|
||||
CREATE TABLE `items` (
|
||||
`id` int NOT NULL AUTO_INCREMENT,
|
||||
`item_name` varchar(255) NOT NULL,
|
||||
`can_borrow_role` varchar(255) NOT NULL,
|
||||
`can_borrow_role` INT NOT NULL,
|
||||
`inSafe` tinyint(1) NOT NULL DEFAULT '1',
|
||||
PRIMARY KEY (`id`),
|
||||
UNIQUE KEY `item_name` (`item_name`)
|
||||
@@ -42,28 +43,95 @@ CREATE TABLE `lockers` (
|
||||
UNIQUE KEY `locker_number` (`locker_number`)
|
||||
);
|
||||
|
||||
-- Mock data
|
||||
-- Mock data for users
|
||||
INSERT INTO `users` (`username`, `password`, `role`) VALUES
|
||||
('alice', 'password1', 1),
|
||||
('bob', 'password2', 2),
|
||||
('carol', 'password3', 1),
|
||||
('dave', 'password4', 3),
|
||||
('eve', 'password5', 2),
|
||||
('frank', 'password6', 1),
|
||||
('grace', 'password7', 2),
|
||||
('heidi', 'password8', 3),
|
||||
('ivan', 'password9', 1),
|
||||
('judy', 'password10', 2),
|
||||
('mallory', 'password11', 1),
|
||||
('oscar', 'password12', 3),
|
||||
('peggy', 'password13', 2),
|
||||
('trent', 'password14', 1),
|
||||
('victor', 'password15', 2),
|
||||
('wendy', 'password16', 3),
|
||||
('zoe', 'password17', 1),
|
||||
('quinn', 'password18', 2),
|
||||
('ruth', 'password19', 1),
|
||||
('sam', 'password20', 3);
|
||||
|
||||
-- Users
|
||||
INSERT INTO users (username, password) VALUES
|
||||
('alice', 'password123'),
|
||||
('bob', 'securepass'),
|
||||
('charlie', 'charliepwd');
|
||||
-- Mock data for loans
|
||||
INSERT INTO `loans` (`username`, `loan_code`, `start_date`, `end_date`, `returned_date`, `loaned_items_id`, `loaned_items_name`)
|
||||
VALUES
|
||||
('alice', 1001, '2025-08-01 09:00:00', '2025-08-10 09:00:00', NULL, '[1,2]', '["Laptop","Projector"]'),
|
||||
('bob', 1002, '2025-08-02 10:00:00', '2025-08-12 10:00:00', NULL, '[3]', '["Tablet"]'),
|
||||
('carol', 1003, '2025-08-03 11:00:00', '2025-08-13 11:00:00', NULL, '[4,5]', '["Camera","Tripod"]'),
|
||||
('dave', 1004, '2025-08-04 12:00:00', '2025-08-14 12:00:00', NULL, '[6]', '["Microphone"]'),
|
||||
('eve', 1005, '2025-08-05 13:00:00', '2025-08-15 13:00:00', NULL, '[7,8]', '["Speaker","Monitor"]'),
|
||||
('frank', 1006, '2025-08-06 14:00:00', '2025-08-16 14:00:00', NULL, '[9]', '["Keyboard"]'),
|
||||
('grace', 1007, '2025-08-07 15:00:00', '2025-08-17 15:00:00', NULL, '[10,11]', '["Mouse","Printer"]'),
|
||||
('heidi', 1008, '2025-08-08 16:00:00', '2025-08-18 16:00:00', NULL, '[12]', '["Scanner"]'),
|
||||
('ivan', 1009, '2025-08-09 17:00:00', '2025-08-19 17:00:00', NULL, '[13,14]', '["Router","Switch"]'),
|
||||
('judy', 1010, '2025-08-10 18:00:00', '2025-08-20 18:00:00', NULL, '[15]', '["Projector"]'),
|
||||
('mallory', 1011, '2025-08-11 09:00:00', '2025-08-21 09:00:00', NULL, '[16,17]', '["Laptop","Tablet"]'),
|
||||
('oscar', 1012, '2025-08-12 10:00:00', '2025-08-22 10:00:00', NULL, '[18]', '["Camera"]'),
|
||||
('peggy', 1013, '2025-08-13 11:00:00', '2025-08-23 11:00:00', NULL, '[19,20]', '["Tripod","Microphone"]'),
|
||||
('trent', 1014, '2025-08-14 12:00:00', '2025-08-24 12:00:00', NULL, '[1]', '["Laptop"]'),
|
||||
('victor', 1015, '2025-08-15 13:00:00', '2025-08-25 13:00:00', NULL, '[2,3]', '["Projector","Tablet"]'),
|
||||
('wendy', 1016, '2025-08-16 14:00:00', '2025-08-26 14:00:00', NULL, '[4]', '["Camera"]'),
|
||||
('zoe', 1017, '2025-08-17 15:00:00', '2025-08-27 15:00:00', NULL, '[5,6]', '["Tripod","Microphone"]'),
|
||||
('quinn', 1018, '2025-08-18 16:00:00', '2025-08-28 16:00:00', NULL, '[7]', '["Speaker"]'),
|
||||
('ruth', 1019, '2025-08-19 17:00:00', '2025-08-29 17:00:00', NULL, '[8,9]', '["Monitor","Keyboard"]'),
|
||||
('sam', 1020, '2025-08-20 18:00:00', '2025-08-30 18:00:00', NULL, '[10]', '["Mouse"]');
|
||||
|
||||
-- Items
|
||||
INSERT INTO items (item_name, can_borrow_role) VALUES
|
||||
('Laptop', 'student'),
|
||||
('Projector', 'teacher'),
|
||||
('Tablet', 'student,teacher');
|
||||
-- Mock data for items
|
||||
INSERT INTO `items` (`item_name`, `can_borrow_role`, `inSafe`) VALUES
|
||||
('Laptop', 1, 1),
|
||||
('Projector', 2, 1),
|
||||
('Tablet', 1, 1),
|
||||
('Camera', 2, 1),
|
||||
('Tripod', 1, 1),
|
||||
('Microphone', 3, 1),
|
||||
('Speaker', 2, 1),
|
||||
('Monitor', 1, 1),
|
||||
('Keyboard', 2, 1),
|
||||
('Mouse', 1, 1),
|
||||
('Printer', 3, 1),
|
||||
('Scanner', 2, 1),
|
||||
('Router', 1, 1),
|
||||
('Switch', 2, 1),
|
||||
('Charger', 1, 1),
|
||||
('USB Cable', 2, 1),
|
||||
('HDMI Cable', 1, 1),
|
||||
('Webcam', 3, 1),
|
||||
('Headphones', 2, 1),
|
||||
('Smartphone', 1, 1);
|
||||
|
||||
-- Loans
|
||||
INSERT INTO loans (username, loan_code, start_date, end_date, returned_date) VALUES
|
||||
('alice', 100001, '2025-08-01 09:00:00', '2025-08-10 17:00:00', NULL),
|
||||
('bob', 100002, '2025-08-05 10:00:00', '2025-08-12 15:00:00', '2025-08-12 14:30:00'),
|
||||
('charlie', 100003, '2025-08-07 11:00:00', '2025-08-15 16:00:00', NULL);
|
||||
|
||||
-- Lockers
|
||||
INSERT INTO lockers (item, locker_number) VALUES
|
||||
-- Mock data for lockers
|
||||
INSERT INTO `lockers` (`item`, `locker_number`) VALUES
|
||||
('Laptop', 101),
|
||||
('Projector', 102),
|
||||
('Tablet', 103);
|
||||
('Tablet', 103),
|
||||
('Camera', 104),
|
||||
('Tripod', 105),
|
||||
('Microphone', 106),
|
||||
('Speaker', 107),
|
||||
('Monitor', 108),
|
||||
('Keyboard', 109),
|
||||
('Mouse', 110),
|
||||
('Printer', 111),
|
||||
('Scanner', 112),
|
||||
('Router', 113),
|
||||
('Switch', 114),
|
||||
('Charger', 115),
|
||||
('USB Cable', 116),
|
||||
('HDMI Cable', 117),
|
||||
('Webcam', 118),
|
||||
('Headphones', 119),
|
||||
('Smartphone', 120);
|
@@ -41,3 +41,211 @@ export const getItemsFromDatabase = async (role) => {
|
||||
}
|
||||
return { success: false };
|
||||
};
|
||||
|
||||
export const getLoansFromDatabase = async () => {
|
||||
const [result] = await pool.query("SELECT * FROM loans;");
|
||||
if (result.length > 0) {
|
||||
return { success: true, data: result };
|
||||
}
|
||||
return { success: false };
|
||||
};
|
||||
|
||||
export const getUserLoansFromDatabase = async (username) => {
|
||||
const [result] = await pool.query("SELECT * FROM loans WHERE username = ?;", [
|
||||
username,
|
||||
]);
|
||||
if (result.length > 0) {
|
||||
return { success: true, data: result };
|
||||
} else if (result.length == 0) {
|
||||
return { success: true, data: "No loans found for this user" };
|
||||
} else {
|
||||
return { success: false };
|
||||
}
|
||||
};
|
||||
|
||||
export const deleteLoanFromDatabase = async (loanId) => {
|
||||
const [result] = await pool.query("DELETE FROM loans WHERE id = ?;", [
|
||||
loanId,
|
||||
]);
|
||||
if (result.affectedRows > 0) {
|
||||
return { success: true };
|
||||
} else {
|
||||
return { success: false };
|
||||
}
|
||||
};
|
||||
|
||||
export const getBorrowableItemsFromDatabase = async (
|
||||
startDate,
|
||||
endDate,
|
||||
role = 0
|
||||
) => {
|
||||
// Overlap if: loan.start < end AND effective_end > start
|
||||
// effective_end is returned_date if set, otherwise end_date
|
||||
const hasRoleFilter = Number(role) > 0;
|
||||
|
||||
const sql = `
|
||||
SELECT i.*
|
||||
FROM items i
|
||||
WHERE ${hasRoleFilter ? "i.can_borrow_role >= ? AND " : ""}NOT EXISTS (
|
||||
SELECT 1
|
||||
FROM loans l
|
||||
JOIN JSON_TABLE(l.loaned_items_id, '$[*]' COLUMNS (item_id INT PATH '$')) jt
|
||||
WHERE jt.item_id = i.id
|
||||
AND l.start_date < ?
|
||||
AND COALESCE(l.returned_date, l.end_date) > ?
|
||||
);
|
||||
`;
|
||||
|
||||
const params = hasRoleFilter
|
||||
? [role, endDate, startDate]
|
||||
: [endDate, startDate];
|
||||
|
||||
const [rows] = await pool.query(sql, params);
|
||||
if (rows.length > 0) {
|
||||
return { success: true, data: rows };
|
||||
}
|
||||
return { success: false };
|
||||
};
|
||||
|
||||
export const createLoanInDatabase = async (
|
||||
username,
|
||||
startDate,
|
||||
endDate,
|
||||
itemIds
|
||||
) => {
|
||||
if (!username)
|
||||
return { success: false, code: "BAD_REQUEST", message: "Missing username" };
|
||||
if (!Array.isArray(itemIds) || itemIds.length === 0)
|
||||
return {
|
||||
success: false,
|
||||
code: "BAD_REQUEST",
|
||||
message: "No items provided",
|
||||
};
|
||||
if (!startDate || !endDate)
|
||||
return { success: false, code: "BAD_REQUEST", message: "Missing dates" };
|
||||
|
||||
const start = new Date(startDate);
|
||||
const end = new Date(endDate);
|
||||
if (
|
||||
!(start instanceof Date) ||
|
||||
isNaN(start.getTime()) ||
|
||||
!(end instanceof Date) ||
|
||||
isNaN(end.getTime()) ||
|
||||
start >= end
|
||||
) {
|
||||
return {
|
||||
success: false,
|
||||
code: "BAD_REQUEST",
|
||||
message: "Invalid date range",
|
||||
};
|
||||
}
|
||||
|
||||
const conn = await pool.getConnection();
|
||||
try {
|
||||
await conn.beginTransaction();
|
||||
|
||||
// Ensure all items exist and collect names
|
||||
const [itemsRows] = await conn.query(
|
||||
"SELECT id, item_name FROM items WHERE id IN (?)",
|
||||
[itemIds]
|
||||
);
|
||||
if (!itemsRows || itemsRows.length !== itemIds.length) {
|
||||
await conn.rollback();
|
||||
return {
|
||||
success: false,
|
||||
code: "BAD_REQUEST",
|
||||
message: "One or more items not found",
|
||||
};
|
||||
}
|
||||
const itemNames = itemIds
|
||||
.map(
|
||||
(id) => itemsRows.find((r) => Number(r.id) === Number(id))?.item_name
|
||||
)
|
||||
.filter(Boolean);
|
||||
|
||||
// Check availability (no overlap with existing loans)
|
||||
const [confRows] = await conn.query(
|
||||
`
|
||||
SELECT COUNT(*) AS conflicts
|
||||
FROM loans l
|
||||
JOIN JSON_TABLE(l.loaned_items_id, '$[*]' COLUMNS (item_id INT PATH '$')) jt
|
||||
ON TRUE
|
||||
WHERE jt.item_id IN (?)
|
||||
AND l.start_date < ?
|
||||
AND COALESCE(l.returned_date, l.end_date) > ?
|
||||
`,
|
||||
[itemIds, end, start]
|
||||
);
|
||||
if (confRows?.[0]?.conflicts > 0) {
|
||||
await conn.rollback();
|
||||
return {
|
||||
success: false,
|
||||
code: "CONFLICT",
|
||||
message: "One or more items are not available in the selected period",
|
||||
};
|
||||
}
|
||||
|
||||
// Generate unique loan_code (retry a few times)
|
||||
let loanCode = null;
|
||||
for (let i = 0; i < 6; i++) {
|
||||
const candidate = Math.floor(1000 + Math.random() * 900000); // 4-6 digits
|
||||
const [exists] = await conn.query(
|
||||
"SELECT 1 FROM loans WHERE loan_code = ? LIMIT 1",
|
||||
[candidate]
|
||||
);
|
||||
if (exists.length === 0) {
|
||||
loanCode = candidate;
|
||||
break;
|
||||
}
|
||||
}
|
||||
if (!loanCode) {
|
||||
await conn.rollback();
|
||||
return {
|
||||
success: false,
|
||||
code: "SERVER_ERROR",
|
||||
message: "Failed to generate unique loan code",
|
||||
};
|
||||
}
|
||||
|
||||
// Insert loan
|
||||
const [insertRes] = await conn.query(
|
||||
`
|
||||
INSERT INTO loans (username, loan_code, start_date, end_date, loaned_items_id, loaned_items_name)
|
||||
VALUES (?, ?, ?, ?, CAST(? AS JSON), CAST(? AS JSON))
|
||||
`,
|
||||
[
|
||||
username,
|
||||
loanCode,
|
||||
// Use DATETIME/TIMESTAMP friendly format
|
||||
new Date(start).toISOString().slice(0, 19).replace("T", " "),
|
||||
new Date(end).toISOString().slice(0, 19).replace("T", " "),
|
||||
JSON.stringify(itemIds.map((n) => Number(n))),
|
||||
JSON.stringify(itemNames),
|
||||
]
|
||||
);
|
||||
|
||||
await conn.commit();
|
||||
return {
|
||||
success: true,
|
||||
data: {
|
||||
id: insertRes.insertId,
|
||||
loan_code: loanCode,
|
||||
username,
|
||||
start_date: start,
|
||||
end_date: end,
|
||||
items: itemIds,
|
||||
item_names: itemNames,
|
||||
},
|
||||
};
|
||||
} catch (err) {
|
||||
await conn.rollback();
|
||||
console.error("createLoanInDatabase error:", err);
|
||||
return {
|
||||
success: false,
|
||||
code: "SERVER_ERROR",
|
||||
message: "Failed to create loan",
|
||||
};
|
||||
} finally {
|
||||
conn.release();
|
||||
}
|
||||
};
|
||||
|
Reference in New Issue
Block a user