Changes between Version 4 and Version 5 of App


Ignore:
Timestamp:
09/30/25 11:18:45 (2 weeks ago)
Author:
211561
Comment:

--

Legend:

Unmodified
Added
Removed
Modified
  • App

    v4 v5  
    187187}}}
    188188
    189 = Трансакции
     189= Процедури
     190
     191== Креирај нарачка и резервира залиха од партија
     192
     193Примa влезни параметри ({{{buyer_id}}}, {{{batch_id}}}, {{{quantity}}}) и креира нарачка, ред во {{{ORDER_BATCHES}}} и автоматски пресметува {{{total_price}}}. Ако нема доволно {{{units_per_batch}}} враќа грешка и откажува.
     194
     195{{{
     196CREATE PROCEDURE create_order_from_batch(IN p_buyer_id VARCHAR(50), IN p_batch_id VARCHAR(50), IN p_quantity INT)
     197BEGIN
     198DECLARE v_product_id VARCHAR(50);
     199DECLARE v_price DECIMAL(18,2);
     200DECLARE v_units INT;
     201DECLARE v_total DECIMAL(18,2);
     202DECLARE v_order_id VARCHAR(50);
     203SELECT product_id, units_per_batch INTO v_product_id, v_units FROM BATCHES WHERE id = p_batch_id FOR UPDATE;
     204IF v_units IS NULL THEN
     205SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = 'Batch not found';
     206END IF;
     207IF p_quantity > v_units THEN
     208SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = 'Insufficient units in batch';
     209END IF;
     210SELECT price INTO v_price FROM PRODUCTS WHERE id = v_product_id;
     211SET v_total = v_price * p_quantity;
     212SET v_order_id = CONCAT('o_',UUID());
     213INSERT INTO ORDERS (id, date, status, estimated_delivery_date, buyer_id, receiver_id) VALUES (v_order_id, CURRENT_DATE, 'pending', DATE_ADD(CURRENT_DATE, INTERVAL 7 DAY), p_buyer_id, p_buyer_id);
     214INSERT INTO ORDER_BATCHES (id, order_id, batch_id, quantity, price_per_unit, total_price, created_at, updated_at) VALUES (CONCAT('ob_',UUID()), v_order_id, p_batch_id, p_quantity, v_price, v_total, NOW(), NOW());
     215UPDATE BATCHES SET units_per_batch = units_per_batch - p_quantity WHERE id = p_batch_id;
     216END;
     217}}}
     218
     219== Поврат на партија и креирање кредит нота
     220
     221Примa {{{order_batch_id}}} и {{{reason}}}; враќа количина во {{{BATCHES}}}, ажурира {{{ORDER_BATCHES}}} и креира негативен {{{PAYMENTS}}} запис како кредит.
     222
     223{{{
     224CREATE PROCEDURE return_batch_and_credit(IN p_order_batch_id VARCHAR(50), IN p_reason VARCHAR(255))
     225BEGIN
     226DECLARE v_batch_id VARCHAR(50);
     227DECLARE v_quantity INT;
     228DECLARE v_total DECIMAL(18,2);
     229DECLARE v_order_id VARCHAR(50);
     230SELECT batch_id, quantity, total_price, order_id INTO v_batch_id, v_quantity, v_total, v_order_id FROM ORDER_BATCHES WHERE id = p_order_batch_id FOR UPDATE;
     231IF v_batch_id IS NULL THEN
     232SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = 'Order batch not found';
     233END IF;
     234UPDATE BATCHES SET units_per_batch = units_per_batch + v_quantity WHERE id = v_batch_id;
     235UPDATE ORDER_BATCHES SET quantity = 0, total_price = 0.00, updated_at = NOW() WHERE id = p_order_batch_id;
     236INSERT INTO PAYMENTS (id, order_id, amount, currency, due_date, exchange_rate, payment_date, payment_method, payment_status) VALUES (CONCAT('pay_cr_',UUID()), v_order_id, -v_total, 'EUR', CURRENT_DATE, 1.00, CURRENT_DATE, 'credit_note', 'refunded');
     237END;
     238}}}
     239
     240== Автоматско консолидирање на нарачки за транспорт
     241
     242Примa {{{transport_id}}} и список на {{{order_ids}}} ({{{CSV}}}); поврзува секоја нарачка со транспорт и ажурира статус на {{{orders}}} на {{{'in_transit'}}}.
     243
     244{{{
     245CREATE PROCEDURE consolidate_orders_to_transport(IN p_transport_id VARCHAR(50), IN p_order_ids TEXT)
     246BEGIN
     247DECLARE v_order_id VARCHAR(50);
     248DECLARE v_pos INT DEFAULT 1;
     249DECLARE v_len INT;
     250DECLARE v_token VARCHAR(100);
     251SET v_len = CHAR_LENGTH(p_order_ids);
     252WHILE v_pos <= v_len DO
     253SET v_token = TRIM(SUBSTRING_INDEX(SUBSTRING_INDEX(p_order_ids, ',', v_pos), ',', -1));
     254IF v_token <> '' THEN
     255UPDATE ORDERS SET transport_id = p_transport_id, status = 'in_transit' WHERE id = v_token;
     256END IF;
     257SET v_pos = v_pos + 1;
     258IF v_pos > 1000 THEN LEAVE; END IF;
     259END WHILE;
     260END;
     261}}}
     262
     263== Евиденција на увоз со конверзија на валута
     264
     265Примa {{{order_id}}} и {{{exchange_rate}}}; ажурира {{{PAYMENTS.exchange_rate}}} и пресметува {{{amount}}} во локална валута, поставува {{{payment_status}}} на {{{'pending'}}}.
     266
     267{{{
     268CREATE PROCEDURE record_import_with_exchange(IN p_order_id VARCHAR(50), IN p_exchange_rate DECIMAL(12,4))
     269BEGIN
     270DECLARE v_amount DECIMAL(18,2);
     271SELECT amount INTO v_amount FROM PAYMENTS WHERE order_id = p_order_id FOR UPDATE;
     272IF v_amount IS NULL THEN
     273SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = 'Payment not found for order';
     274END IF;
     275UPDATE PAYMENTS SET exchange_rate = p_exchange_rate, payment_status = 'pending' WHERE order_id = p_order_id;
     276END;
     277}}}
     278
     279== Симулација на рок на траење и известување за истекување
     280
     281Примa {{{days_ahead}}} и враќа листа со {{{batch_id}}} и {{{days_until_expiry}}} за сите серии кои истекуваат во рок од {{{days_ahead}}}; дополнително ажурира поле {{{status}}} во {{{BATCHES}}}.
     282
     283{{{
     284CREATE PROCEDURE upcoming_expirations(IN p_days_ahead INT)
     285BEGIN
     286SELECT id AS batch_id, DATEDIFF(expiration_date, CURRENT_DATE) AS days_until_expiry FROM BATCHES WHERE DATEDIFF(expiration_date, CURRENT_DATE) <= p_days_ahead;
     287END;
     288}}}
     289
     290= Погледи
     291
     292== {{{active_orders_overview}}}
     293
     294Преглед на активни (processing, pending, in_transit) нарачки со вкупна сума и број на различни партији.
     295
     296{{{
     297CREATE VIEW active_orders_overview AS
     298SELECT
     299  o.id AS order_id,
     300  o.date AS order_date,
     301  o.status,
     302  o.buyer_id,
     303  o.receiver_id,
     304  COALESCE(SUM(ob.total_price),0) AS total_order_value,
     305  COUNT(DISTINCT ob.batch_id) AS batches_count
     306FROM ORDERS o
     307LEFT JOIN ORDER_BATCHES ob ON ob.order_id = o.id
     308WHERE o.status IN ('processing','pending','in_transit')
     309GROUP BY o.id, o.date, o.status, o.buyer_id, o.receiver_id;
     310}}}
     311
     312== {{{product_stock_summary}}}
     313
     314{{{
     315CREATE VIEW product_stock_summary AS
     316SELECT
     317  p.id AS product_id,
     318  p.name AS product_name,
     319  p.unit_of_measure,
     320  COALESCE(SUM(b.units_per_batch),0) AS total_units_available,
     321  COALESCE(AVG(p.price),0) AS avg_price
     322FROM PRODUCTS p
     323LEFT JOIN BATCHES b ON b.product_id = p.id
     324GROUP BY p.id, p.name, p.unit_of_measure;
     325}}}
     326
     327== {{{client_financial_position}}}
     328
     329Финансиска состојба по клиент — вкупно фактурирано, платено и останат долг.
     330
     331{{{
     332CREATE VIEW client_financial_position AS
     333SELECT
     334  c.id AS client_id,
     335  c.name AS client_name,
     336  COALESCE(SUM(pay.amount),0) AS total_invoiced_amount,
     337  COALESCE(SUM(CASE WHEN pay.payment_status IN ('paid','refunded') THEN pay.amount ELSE 0 END),0) AS total_cleared_amount,
     338  COALESCE(SUM(CASE WHEN pay.payment_status NOT IN ('paid','refunded') THEN pay.amount ELSE 0 END),0) AS outstanding_amount
     339FROM CLIENTS c
     340LEFT JOIN ORDERS o ON o.buyer_id = c.id
     341LEFT JOIN PAYMENTS pay ON pay.order_id = o.id
     342GROUP BY c.id, c.name;
     343}}}
     344
     345== {{{batches_near_expiry}}}
     346
     347Список на партији кои истекуваат во следните 30 дена (може да се користи и со WHERE услов за други периоди).
     348
     349{{{
     350CREATE VIEW batches_near_expiry AS
     351SELECT
     352  b.id AS batch_id,
     353  b.batch_code,
     354  b.product_id,
     355  p.name AS product_name,
     356  b.expiration_date,
     357  DATEDIFF(b.expiration_date, CURRENT_DATE) AS days_until_expiry,
     358  b.units_per_batch
     359FROM BATCHES b
     360LEFT JOIN PRODUCTS p ON p.id = b.product_id
     361WHERE DATEDIFF(b.expiration_date, CURRENT_DATE) BETWEEN 0 AND 30;
     362}}}
     363
     364== {{{transport_load_summary}}}
     365
     366Консолидиран преглед на транспортните единици со вкупен број на нарачки и вкупна тежина (приближно, користи net_weight * quantity).
     367
     368{{{
     369CREATE VIEW transport_load_summary AS
     370SELECT
     371  t.id AS transport_id,
     372  t.name AS transport_name,
     373  t.departure_point,
     374  t.arrival_point,
     375  COUNT(DISTINCT o.id) AS orders_count,
     376  COALESCE(SUM(b.net_weight * ob.quantity),0) AS approximate_total_net_weight
     377FROM TRANSPORTS t
     378LEFT JOIN ORDERS o ON o.transport_id = t.id
     379LEFT JOIN ORDER_BATCHES ob ON ob.order_id = o.id
     380LEFT JOIN BATCHES b ON b.id = ob.batch_id
     381GROUP BY t.id, t.name, t.departure_point, t.arrival_point;
     382}}}