573 lines
16 KiB
SQL
573 lines
16 KiB
SQL
-- database/enhancement.sql
|
|
-- ============================================
|
|
-- ENHANCEMENT FOR LOST & FOUND DATABASE
|
|
-- Stored Procedures, Functions, Triggers, Views
|
|
-- ============================================
|
|
DELIMITER $$
|
|
|
|
-- ============================================
|
|
-- FUNCTIONS
|
|
-- ============================================
|
|
|
|
-- Function: Hitung similarity score antara 2 string
|
|
CREATE FUNCTION fn_calculate_similarity(str1 TEXT, str2 TEXT)
|
|
RETURNS DECIMAL(5,2)
|
|
DETERMINISTIC
|
|
BEGIN
|
|
DECLARE similarity DECIMAL(5,2);
|
|
DECLARE len1 INT;
|
|
DECLARE len2 INT;
|
|
DECLARE common_words INT DEFAULT 0;
|
|
|
|
SET len1 = LENGTH(str1);
|
|
SET len2 = LENGTH(str2);
|
|
|
|
-- Simple similarity calculation (bisa diganti dengan algorithm lebih kompleks)
|
|
IF str1 = str2 THEN
|
|
SET similarity = 100.00;
|
|
ELSEIF LOCATE(LOWER(str1), LOWER(str2)) > 0 THEN
|
|
SET similarity = 75.00;
|
|
ELSE
|
|
SET similarity = 50.00;
|
|
END IF;
|
|
|
|
RETURN similarity;
|
|
END$$
|
|
|
|
-- Function: Check apakah item sudah expired
|
|
CREATE FUNCTION fn_is_item_expired(item_id INT)
|
|
RETURNS BOOLEAN
|
|
READS SQL DATA
|
|
BEGIN
|
|
DECLARE is_expired BOOLEAN DEFAULT FALSE;
|
|
DECLARE expire_date TIMESTAMP;
|
|
|
|
SELECT expires_at INTO expire_date
|
|
FROM items
|
|
WHERE id = item_id AND deleted_at IS NULL;
|
|
|
|
IF expire_date IS NOT NULL AND expire_date < NOW() THEN
|
|
SET is_expired = TRUE;
|
|
END IF;
|
|
|
|
RETURN is_expired;
|
|
END$$
|
|
|
|
-- Function: Hitung total items per kategori
|
|
CREATE FUNCTION fn_count_items_by_category(cat_id INT)
|
|
RETURNS INT
|
|
READS SQL DATA
|
|
BEGIN
|
|
DECLARE total INT DEFAULT 0;
|
|
|
|
SELECT COUNT(*) INTO total
|
|
FROM items
|
|
WHERE category_id = cat_id
|
|
AND deleted_at IS NULL
|
|
AND status = 'unclaimed';
|
|
|
|
RETURN total;
|
|
END$$
|
|
|
|
-- ============================================
|
|
-- STORED PROCEDURES
|
|
-- ============================================
|
|
|
|
-- Procedure: Create claim dengan transaction dan locking
|
|
CREATE PROCEDURE sp_create_claim(
|
|
IN p_item_id INT,
|
|
IN p_user_id INT,
|
|
IN p_description TEXT,
|
|
IN p_proof_url VARCHAR(255),
|
|
IN p_contact VARCHAR(50),
|
|
OUT p_claim_id INT,
|
|
OUT p_status VARCHAR(50),
|
|
OUT p_message TEXT
|
|
)
|
|
BEGIN
|
|
DECLARE v_item_status VARCHAR(50);
|
|
DECLARE v_item_desc TEXT;
|
|
DECLARE v_similarity DECIMAL(5,2);
|
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
|
BEGIN
|
|
ROLLBACK;
|
|
SET p_status = 'error';
|
|
SET p_message = 'Transaction failed. Claim not created.';
|
|
SET p_claim_id = NULL;
|
|
END;
|
|
|
|
START TRANSACTION;
|
|
|
|
-- Lock item untuk prevent concurrent claims
|
|
SELECT status, description INTO v_item_status, v_item_desc
|
|
FROM items
|
|
WHERE id = p_item_id AND deleted_at IS NULL
|
|
FOR UPDATE;
|
|
|
|
-- Validasi: item harus unclaimed
|
|
IF v_item_status != 'unclaimed' THEN
|
|
SET p_status = 'error';
|
|
SET p_message = 'Item sudah diklaim atau tidak tersedia';
|
|
ROLLBACK;
|
|
ELSE
|
|
-- Insert claim
|
|
INSERT INTO claims (
|
|
item_id, user_id, description,
|
|
proof_url, contact, status
|
|
) VALUES (
|
|
p_item_id, p_user_id, p_description,
|
|
p_proof_url, p_contact, 'pending'
|
|
);
|
|
|
|
SET p_claim_id = LAST_INSERT_ID();
|
|
|
|
-- Calculate similarity score
|
|
SET v_similarity = fn_calculate_similarity(p_description, v_item_desc);
|
|
|
|
-- Insert verification record
|
|
INSERT INTO claim_verifications (
|
|
claim_id, similarity_score, is_auto_matched
|
|
) VALUES (
|
|
p_claim_id, v_similarity, FALSE
|
|
);
|
|
|
|
-- Create notification for managers
|
|
INSERT INTO notifications (
|
|
user_id, type, title, message, entity_type, entity_id
|
|
)
|
|
SELECT
|
|
u.id,
|
|
'new_claim',
|
|
'Klaim Baru',
|
|
CONCAT('Ada klaim baru untuk barang: ', i.name),
|
|
'claim',
|
|
p_claim_id
|
|
FROM users u
|
|
CROSS JOIN items i
|
|
WHERE u.role_id = 2
|
|
AND u.deleted_at IS NULL
|
|
AND i.id = p_item_id;
|
|
|
|
SET p_status = 'success';
|
|
SET p_message = 'Claim created successfully';
|
|
|
|
COMMIT;
|
|
END IF;
|
|
END$$
|
|
|
|
-- Procedure: Verify claim (approve/reject)
|
|
CREATE PROCEDURE sp_verify_claim(
|
|
IN p_claim_id INT,
|
|
IN p_verifier_id INT,
|
|
IN p_action VARCHAR(20), -- 'approve' or 'reject'
|
|
IN p_notes TEXT,
|
|
OUT p_status VARCHAR(50),
|
|
OUT p_message TEXT
|
|
)
|
|
BEGIN
|
|
DECLARE v_item_id INT;
|
|
DECLARE v_user_id INT;
|
|
DECLARE v_claim_status VARCHAR(50);
|
|
|
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
|
BEGIN
|
|
ROLLBACK;
|
|
SET p_status = 'error';
|
|
SET p_message = 'Verification failed';
|
|
END;
|
|
|
|
START TRANSACTION;
|
|
|
|
-- Get claim details with lock
|
|
SELECT item_id, user_id, status
|
|
INTO v_item_id, v_user_id, v_claim_status
|
|
FROM claims
|
|
WHERE id = p_claim_id AND deleted_at IS NULL
|
|
FOR UPDATE;
|
|
|
|
IF v_claim_status != 'pending' THEN
|
|
SET p_status = 'error';
|
|
SET p_message = 'Claim already processed';
|
|
ROLLBACK;
|
|
ELSE
|
|
-- Update claim status
|
|
UPDATE claims
|
|
SET status = p_action,
|
|
notes = p_notes,
|
|
verified_at = NOW(),
|
|
verified_by = p_verifier_id
|
|
WHERE id = p_claim_id;
|
|
|
|
-- If approved, update item status
|
|
IF p_action = 'approved' THEN
|
|
UPDATE items
|
|
SET status = 'claimed'
|
|
WHERE id = v_item_id;
|
|
|
|
-- Archive the item
|
|
INSERT INTO archives (
|
|
item_id, name, category_id, photo_url, location,
|
|
description, date_found, status, reporter_name,
|
|
reporter_contact, archived_reason, claimed_by
|
|
)
|
|
SELECT
|
|
id, name, category_id, photo_url, location,
|
|
description, date_found, status, reporter_name,
|
|
reporter_contact, 'case_closed', v_user_id
|
|
FROM items
|
|
WHERE id = v_item_id;
|
|
END IF;
|
|
|
|
-- Notify user
|
|
INSERT INTO notifications (
|
|
user_id, type, title, message, entity_type, entity_id
|
|
) VALUES (
|
|
v_user_id,
|
|
CONCAT('claim_', p_action),
|
|
IF(p_action = 'approved', 'Klaim Disetujui!', 'Klaim Ditolak'),
|
|
CONCAT('Klaim Anda telah ', IF(p_action = 'approved', 'disetujui', 'ditolak')),
|
|
'claim',
|
|
p_claim_id
|
|
);
|
|
|
|
SET p_status = 'success';
|
|
SET p_message = CONCAT('Claim ', p_action, ' successfully');
|
|
|
|
COMMIT;
|
|
END IF;
|
|
END$$
|
|
|
|
-- Procedure: Archive expired items
|
|
CREATE PROCEDURE sp_archive_expired_items(
|
|
OUT p_archived_count INT
|
|
)
|
|
BEGIN
|
|
DECLARE done INT DEFAULT FALSE;
|
|
DECLARE v_item_id INT;
|
|
DECLARE cur CURSOR FOR
|
|
SELECT id FROM items
|
|
WHERE expires_at < NOW()
|
|
AND status = 'unclaimed'
|
|
AND deleted_at IS NULL;
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
|
|
|
|
SET p_archived_count = 0;
|
|
|
|
OPEN cur;
|
|
|
|
read_loop: LOOP
|
|
FETCH cur INTO v_item_id;
|
|
IF done THEN
|
|
LEAVE read_loop;
|
|
END IF;
|
|
|
|
-- Archive the item
|
|
INSERT INTO archives (
|
|
item_id, name, category_id, photo_url, location,
|
|
description, date_found, status, reporter_name,
|
|
reporter_contact, archived_reason
|
|
)
|
|
SELECT
|
|
id, name, category_id, photo_url, location,
|
|
description, date_found, status, reporter_name,
|
|
reporter_contact, 'expired'
|
|
FROM items
|
|
WHERE id = v_item_id;
|
|
|
|
-- Update item status
|
|
UPDATE items
|
|
SET status = 'expired'
|
|
WHERE id = v_item_id;
|
|
|
|
SET p_archived_count = p_archived_count + 1;
|
|
END LOOP;
|
|
|
|
CLOSE cur;
|
|
END$$
|
|
|
|
-- Procedure: Auto-match lost items with found items
|
|
CREATE PROCEDURE sp_auto_match_items()
|
|
BEGIN
|
|
DECLARE done INT DEFAULT FALSE;
|
|
DECLARE v_lost_id INT;
|
|
DECLARE v_item_id INT;
|
|
DECLARE v_similarity DECIMAL(5,2);
|
|
|
|
DECLARE cur CURSOR FOR
|
|
SELECT li.id, i.id, fn_calculate_similarity(li.description, i.description)
|
|
FROM lost_items li
|
|
CROSS JOIN items i
|
|
WHERE li.status = 'active'
|
|
AND i.status = 'unclaimed'
|
|
AND li.category_id = i.category_id
|
|
AND li.deleted_at IS NULL
|
|
AND i.deleted_at IS NULL
|
|
AND NOT EXISTS (
|
|
SELECT 1 FROM match_results mr
|
|
WHERE mr.lost_item_id = li.id
|
|
AND mr.item_id = i.id
|
|
AND mr.deleted_at IS NULL
|
|
);
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
|
|
|
|
OPEN cur;
|
|
|
|
match_loop: LOOP
|
|
FETCH cur INTO v_lost_id, v_item_id, v_similarity;
|
|
IF done THEN
|
|
LEAVE match_loop;
|
|
END IF;
|
|
|
|
-- Only create match if similarity >= 70%
|
|
IF v_similarity >= 70.00 THEN
|
|
INSERT INTO match_results (
|
|
lost_item_id, item_id, similarity_score,
|
|
matched_fields, is_notified
|
|
) VALUES (
|
|
v_lost_id, v_item_id, v_similarity,
|
|
'{"category": 100, "description": ' || v_similarity || '}',
|
|
FALSE
|
|
);
|
|
|
|
-- Create notification
|
|
INSERT INTO notifications (
|
|
user_id, type, title, message, entity_type, entity_id
|
|
)
|
|
SELECT
|
|
li.user_id,
|
|
'match_found',
|
|
'Barang yang Mirip Ditemukan!',
|
|
CONCAT('Kami menemukan barang yang mirip: ', i.name),
|
|
'match',
|
|
LAST_INSERT_ID()
|
|
FROM lost_items li
|
|
JOIN items i ON i.id = v_item_id
|
|
WHERE li.id = v_lost_id;
|
|
END IF;
|
|
END LOOP;
|
|
|
|
CLOSE cur;
|
|
END$$
|
|
|
|
-- ============================================
|
|
-- TRIGGERS
|
|
-- ============================================
|
|
|
|
-- Trigger: Auto-set expires_at saat item dibuat (3 bulan dari date_found)
|
|
CREATE TRIGGER trg_items_before_insert
|
|
BEFORE INSERT ON items
|
|
FOR EACH ROW
|
|
BEGIN
|
|
IF NEW.expires_at IS NULL THEN
|
|
SET NEW.expires_at = DATE_ADD(NEW.date_found, INTERVAL 3 MONTH);
|
|
END IF;
|
|
END$$
|
|
|
|
-- Trigger: Auto-log ke audit_logs saat user login
|
|
CREATE TRIGGER trg_audit_log_after_user_update
|
|
AFTER UPDATE ON users
|
|
FOR EACH ROW
|
|
BEGIN
|
|
IF OLD.updated_at != NEW.updated_at THEN
|
|
INSERT INTO audit_logs (
|
|
user_id, action, entity_type, entity_id, details
|
|
) VALUES (
|
|
NEW.id,
|
|
'update',
|
|
'user',
|
|
NEW.id,
|
|
CONCAT('User updated: ', NEW.name)
|
|
);
|
|
END IF;
|
|
END$$
|
|
|
|
-- Trigger: Auto-create revision log saat item di-update
|
|
CREATE TRIGGER trg_items_after_update
|
|
AFTER UPDATE ON items
|
|
FOR EACH ROW
|
|
BEGIN
|
|
IF OLD.name != NEW.name THEN
|
|
INSERT INTO revision_logs (item_id, user_id, field_name, old_value, new_value)
|
|
VALUES (NEW.id, NEW.reporter_id, 'name', OLD.name, NEW.name);
|
|
END IF;
|
|
|
|
IF OLD.description != NEW.description THEN
|
|
INSERT INTO revision_logs (item_id, user_id, field_name, old_value, new_value)
|
|
VALUES (NEW.id, NEW.reporter_id, 'description', OLD.description, NEW.description);
|
|
END IF;
|
|
|
|
IF OLD.status != NEW.status THEN
|
|
INSERT INTO revision_logs (item_id, user_id, field_name, old_value, new_value)
|
|
VALUES (NEW.id, NEW.reporter_id, 'status', OLD.status, NEW.status);
|
|
END IF;
|
|
END$$
|
|
|
|
-- Trigger: Prevent delete if item has active claims
|
|
CREATE TRIGGER trg_items_before_delete
|
|
BEFORE DELETE ON items
|
|
FOR EACH ROW
|
|
BEGIN
|
|
DECLARE v_active_claims INT;
|
|
|
|
SELECT COUNT(*) INTO v_active_claims
|
|
FROM claims
|
|
WHERE item_id = OLD.id
|
|
AND status = 'pending'
|
|
AND deleted_at IS NULL;
|
|
|
|
IF v_active_claims > 0 THEN
|
|
SIGNAL SQLSTATE '45000'
|
|
SET MESSAGE_TEXT = 'Cannot delete item with active claims';
|
|
END IF;
|
|
END$$
|
|
|
|
-- Trigger: Auto-archive item when claimed
|
|
CREATE TRIGGER trg_items_after_status_claimed
|
|
AFTER UPDATE ON items
|
|
FOR EACH ROW
|
|
BEGIN
|
|
IF OLD.status != 'claimed' AND NEW.status = 'claimed' THEN
|
|
INSERT INTO archives (
|
|
item_id, name, category_id, photo_url, location,
|
|
description, date_found, status, reporter_name,
|
|
reporter_contact, archived_reason
|
|
) VALUES (
|
|
NEW.id, NEW.name, NEW.category_id, NEW.photo_url,
|
|
NEW.location, NEW.description, NEW.date_found,
|
|
NEW.status, NEW.reporter_name, NEW.reporter_contact,
|
|
'case_closed'
|
|
);
|
|
END IF;
|
|
END$$
|
|
|
|
DELIMITER ;
|
|
|
|
-- ============================================
|
|
-- VIEWS untuk ETL dan Reporting
|
|
-- ============================================
|
|
|
|
-- View: Dashboard statistics
|
|
CREATE OR REPLACE VIEW vw_dashboard_stats AS
|
|
SELECT
|
|
(SELECT COUNT(*) FROM items WHERE status = 'unclaimed' AND deleted_at IS NULL) AS total_unclaimed,
|
|
(SELECT COUNT(*) FROM items WHERE status = 'claimed' AND deleted_at IS NULL) AS total_claimed,
|
|
(SELECT COUNT(*) FROM lost_items WHERE status = 'active' AND deleted_at IS NULL) AS total_lost_reports,
|
|
(SELECT COUNT(*) FROM claims WHERE status = 'pending' AND deleted_at IS NULL) AS pending_claims,
|
|
(SELECT COUNT(*) FROM match_results WHERE is_notified = FALSE AND deleted_at IS NULL) AS unnotified_matches;
|
|
|
|
-- View: Items dengan informasi kategori dan reporter
|
|
CREATE OR REPLACE VIEW vw_items_detail AS
|
|
SELECT
|
|
i.id,
|
|
i.name,
|
|
c.name AS category_name,
|
|
c.slug AS category_slug,
|
|
i.photo_url,
|
|
i.location,
|
|
i.date_found,
|
|
i.status,
|
|
i.reporter_name,
|
|
i.reporter_contact,
|
|
i.expires_at,
|
|
u.name AS reporter_user_name,
|
|
u.email AS reporter_email,
|
|
DATEDIFF(i.expires_at, NOW()) AS days_until_expire,
|
|
i.created_at
|
|
FROM items i
|
|
JOIN categories c ON i.category_id = c.id
|
|
JOIN users u ON i.reporter_id = u.id
|
|
WHERE i.deleted_at IS NULL;
|
|
|
|
-- View: Claims dengan detail lengkap
|
|
CREATE OR REPLACE VIEW vw_claims_detail AS
|
|
SELECT
|
|
c.id,
|
|
c.status,
|
|
i.name AS item_name,
|
|
cat.name AS category_name,
|
|
u.name AS claimant_name,
|
|
u.email AS claimant_email,
|
|
u.phone AS claimant_phone,
|
|
c.description AS claim_description,
|
|
c.contact,
|
|
cv.similarity_score,
|
|
c.verified_at,
|
|
v.name AS verified_by_name,
|
|
c.notes,
|
|
c.created_at
|
|
FROM claims c
|
|
JOIN items i ON c.item_id = i.id
|
|
JOIN categories cat ON i.category_id = cat.id
|
|
JOIN users u ON c.user_id = u.id
|
|
LEFT JOIN claim_verifications cv ON c.id = cv.claim_id
|
|
LEFT JOIN users v ON c.verified_by = v.id
|
|
WHERE c.deleted_at IS NULL;
|
|
|
|
-- View: Match results dengan detail
|
|
CREATE OR REPLACE VIEW vw_match_results_detail AS
|
|
SELECT
|
|
mr.id,
|
|
li.name AS lost_item_name,
|
|
li.user_id AS lost_by_user_id,
|
|
u.name AS lost_by_user_name,
|
|
u.email AS lost_by_email,
|
|
i.name AS found_item_name,
|
|
i.reporter_name AS found_by_name,
|
|
mr.similarity_score,
|
|
mr.is_notified,
|
|
mr.matched_at,
|
|
i.id AS found_item_id,
|
|
li.id AS lost_item_id
|
|
FROM match_results mr
|
|
JOIN lost_items li ON mr.lost_item_id = li.id
|
|
JOIN items i ON mr.item_id = i.id
|
|
JOIN users u ON li.user_id = u.id
|
|
WHERE mr.deleted_at IS NULL
|
|
ORDER BY mr.similarity_score DESC;
|
|
|
|
-- View: Category statistics
|
|
CREATE OR REPLACE VIEW vw_category_stats AS
|
|
SELECT
|
|
c.id,
|
|
c.name,
|
|
c.slug,
|
|
COUNT(DISTINCT i.id) AS total_items,
|
|
COUNT(DISTINCT CASE WHEN i.status = 'unclaimed' THEN i.id END) AS unclaimed_items,
|
|
COUNT(DISTINCT CASE WHEN i.status = 'claimed' THEN i.id END) AS claimed_items,
|
|
COUNT(DISTINCT li.id) AS total_lost_reports
|
|
FROM categories c
|
|
LEFT JOIN items i ON c.id = i.category_id AND i.deleted_at IS NULL
|
|
LEFT JOIN lost_items li ON c.id = li.category_id AND li.deleted_at IS NULL
|
|
WHERE c.deleted_at IS NULL
|
|
GROUP BY c.id, c.name, c.slug;
|
|
|
|
-- ============================================
|
|
-- EVENT SCHEDULER (untuk auto-archiving)
|
|
-- ============================================
|
|
|
|
-- Enable event scheduler
|
|
SET GLOBAL event_scheduler = ON;
|
|
|
|
-- Event: Archive expired items setiap hari jam 1 pagi
|
|
CREATE EVENT IF NOT EXISTS evt_archive_expired_items
|
|
ON SCHEDULE EVERY 1 DAY
|
|
STARTS CURRENT_TIMESTAMP + INTERVAL 1 DAY
|
|
DO
|
|
CALL sp_archive_expired_items(@count);
|
|
|
|
-- Event: Auto-match items setiap 1 jam
|
|
CREATE EVENT IF NOT EXISTS evt_auto_match_items
|
|
ON SCHEDULE EVERY 1 HOUR
|
|
DO
|
|
CALL sp_auto_match_items();
|
|
|
|
-- ============================================
|
|
-- SUCCESS MESSAGE
|
|
-- ============================================
|
|
SELECT '✅ Database enhancements created!' AS Status;
|
|
SELECT '📝 Functions: 3' AS Info;
|
|
SELECT '⚙️ Procedures: 4' AS Info;
|
|
SELECT '🔔 Triggers: 5' AS Info;
|
|
SELECT '📊 Views: 5' AS Info;
|
|
SELECT '⏰ Events: 2' AS Info; |