- Created management command for generating demo orders - Added SQL script to create 25 orders with random dates (±15 days) - Added Python runner script for executing SQL - Demo orders include varied statuses, payment methods, and delivery types - Orders distributed across different dates for testing date filter 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude <noreply@anthropic.com>
187 lines
7.3 KiB
SQL
187 lines
7.3 KiB
SQL
-- Создание демо-заказов для схемы grach
|
||
SET search_path TO grach;
|
||
|
||
-- Создаем 25 заказов с разными датами (от -15 до +15 дней от сегодня)
|
||
DO $$
|
||
DECLARE
|
||
customer_ids INT[];
|
||
product_ids INT[];
|
||
address_ids INT[];
|
||
shop_ids INT[];
|
||
i INT;
|
||
random_customer_id INT;
|
||
random_product_id INT;
|
||
random_address_id INT;
|
||
random_shop_id INT;
|
||
is_delivery_flag BOOLEAN;
|
||
delivery_date_val DATE;
|
||
status_val VARCHAR(20);
|
||
payment_status_val VARCHAR(20);
|
||
payment_method_val VARCHAR(20);
|
||
order_id INT;
|
||
items_total DECIMAL(10,2);
|
||
delivery_cost_val DECIMAL(10,2);
|
||
total_amount_val DECIMAL(10,2);
|
||
BEGIN
|
||
-- Получаем существующие ID
|
||
SELECT ARRAY_AGG(id) INTO customer_ids FROM grach.customers_customer;
|
||
SELECT ARRAY_AGG(id) INTO product_ids FROM grach.products_product;
|
||
SELECT ARRAY_AGG(id) INTO address_ids FROM grach.customers_address;
|
||
SELECT ARRAY_AGG(id) INTO shop_ids FROM grach.shops_shop;
|
||
|
||
-- Проверяем наличие данных
|
||
IF customer_ids IS NULL OR array_length(customer_ids, 1) = 0 THEN
|
||
RAISE EXCEPTION 'Нет клиентов в базе!';
|
||
END IF;
|
||
|
||
IF product_ids IS NULL OR array_length(product_ids, 1) = 0 THEN
|
||
RAISE EXCEPTION 'Нет товаров в базе!';
|
||
END IF;
|
||
|
||
-- Создаем 25 заказов
|
||
FOR i IN 1..25 LOOP
|
||
-- Случайные значения
|
||
random_customer_id := customer_ids[1 + floor(random() * array_length(customer_ids, 1))::int];
|
||
is_delivery_flag := (random() > 0.5);
|
||
delivery_date_val := CURRENT_DATE + (floor(random() * 31) - 15)::int;
|
||
|
||
-- Случайный статус
|
||
CASE floor(random() * 6)::int
|
||
WHEN 0 THEN status_val := 'new';
|
||
WHEN 1 THEN status_val := 'confirmed';
|
||
WHEN 2 THEN status_val := 'in_assembly';
|
||
WHEN 3 THEN status_val := 'in_delivery';
|
||
WHEN 4 THEN status_val := 'delivered';
|
||
ELSE status_val := 'cancelled';
|
||
END CASE;
|
||
|
||
-- Случайный статус оплаты
|
||
CASE floor(random() * 3)::int
|
||
WHEN 0 THEN payment_status_val := 'unpaid';
|
||
WHEN 1 THEN payment_status_val := 'partial';
|
||
ELSE payment_status_val := 'paid';
|
||
END CASE;
|
||
|
||
-- Случайный способ оплаты
|
||
CASE floor(random() * 4)::int
|
||
WHEN 0 THEN payment_method_val := 'cash_to_courier';
|
||
WHEN 1 THEN payment_method_val := 'card_to_courier';
|
||
WHEN 2 THEN payment_method_val := 'online';
|
||
ELSE payment_method_val := 'bank_transfer';
|
||
END CASE;
|
||
|
||
-- Стоимость доставки
|
||
IF is_delivery_flag THEN
|
||
delivery_cost_val := 200 + floor(random() * 300)::int;
|
||
ELSE
|
||
delivery_cost_val := 0;
|
||
END IF;
|
||
|
||
-- Создаем заказ
|
||
INSERT INTO grach.orders_order (
|
||
customer_id,
|
||
order_number,
|
||
is_delivery,
|
||
delivery_address_id,
|
||
pickup_shop_id,
|
||
delivery_date,
|
||
delivery_time_start,
|
||
delivery_time_end,
|
||
delivery_cost,
|
||
status,
|
||
payment_method,
|
||
is_paid,
|
||
total_amount,
|
||
discount_amount,
|
||
amount_paid,
|
||
payment_status,
|
||
customer_is_recipient,
|
||
recipient_name,
|
||
recipient_phone,
|
||
is_anonymous,
|
||
special_instructions,
|
||
created_at,
|
||
updated_at,
|
||
modified_by_id
|
||
) VALUES (
|
||
random_customer_id,
|
||
'ORD-' || to_char(CURRENT_DATE, 'YYYYMMDD') || '-' || substring(md5(random()::text) from 1 for 4),
|
||
is_delivery_flag,
|
||
CASE WHEN is_delivery_flag AND address_ids IS NOT NULL THEN address_ids[1 + floor(random() * array_length(address_ids, 1))::int] ELSE NULL END,
|
||
CASE WHEN NOT is_delivery_flag AND shop_ids IS NOT NULL THEN shop_ids[1 + floor(random() * array_length(shop_ids, 1))::int] ELSE NULL END,
|
||
delivery_date_val,
|
||
CASE WHEN random() > 0.3 THEN ((9 + floor(random() * 10)::int)::text || ':00:00')::time ELSE NULL END,
|
||
CASE WHEN random() > 0.3 THEN ((11 + floor(random() * 8)::int)::text || ':00:00')::time ELSE NULL END,
|
||
delivery_cost_val,
|
||
status_val,
|
||
payment_method_val,
|
||
(payment_status_val = 'paid'),
|
||
1000, -- Временное значение, пересчитаем позже
|
||
CASE WHEN random() > 0.8 THEN (100 + floor(random() * 400)::int) ELSE 0 END,
|
||
0, -- Временное значение
|
||
payment_status_val,
|
||
(random() > 0.7),
|
||
CASE WHEN random() > 0.7 THEN 'Получатель ' || i ELSE NULL END,
|
||
CASE WHEN random() > 0.7 THEN '+79' || lpad(floor(random() * 1000000000)::text, 9, '0') ELSE NULL END,
|
||
(random() > 0.8),
|
||
CASE WHEN random() > 0.5 THEN
|
||
CASE floor(random() * 5)::int
|
||
WHEN 0 THEN 'Позвонить за час до доставки'
|
||
WHEN 1 THEN 'Доставить точно в указанное время'
|
||
WHEN 2 THEN 'Не звонить в дверь'
|
||
WHEN 3 THEN 'Упаковать покрасивее'
|
||
ELSE 'Приложить открытку'
|
||
END
|
||
ELSE NULL END,
|
||
CURRENT_TIMESTAMP,
|
||
CURRENT_TIMESTAMP,
|
||
NULL
|
||
) RETURNING id INTO order_id;
|
||
|
||
-- Добавляем 1-3 товара в заказ
|
||
items_total := 0;
|
||
FOR j IN 1..(1 + floor(random() * 3)::int) LOOP
|
||
random_product_id := product_ids[1 + floor(random() * array_length(product_ids, 1))::int];
|
||
|
||
-- Получаем цену товара и добавляем позицию
|
||
INSERT INTO grach.orders_orderitem (
|
||
order_id,
|
||
product_id,
|
||
product_kit_id,
|
||
quantity,
|
||
price,
|
||
is_custom_price,
|
||
created_at
|
||
)
|
||
SELECT
|
||
order_id,
|
||
random_product_id,
|
||
NULL,
|
||
1 + floor(random() * 3)::int,
|
||
price,
|
||
FALSE,
|
||
CURRENT_TIMESTAMP
|
||
FROM grach.products_product
|
||
WHERE id = random_product_id
|
||
RETURNING (quantity * price) INTO STRICT total_amount_val;
|
||
|
||
items_total := items_total + total_amount_val;
|
||
END LOOP;
|
||
|
||
-- Обновляем итоговую сумму заказа
|
||
UPDATE grach.orders_order
|
||
SET
|
||
total_amount = items_total + delivery_cost - discount_amount,
|
||
amount_paid = CASE
|
||
WHEN payment_status = 'paid' THEN items_total + delivery_cost - discount_amount
|
||
WHEN payment_status = 'partial' THEN (items_total + delivery_cost - discount_amount) * (0.2 + random() * 0.6)
|
||
ELSE 0
|
||
END
|
||
WHERE id = order_id;
|
||
|
||
RAISE NOTICE 'Создан заказ % на дату %', order_id, delivery_date_val;
|
||
END LOOP;
|
||
|
||
RAISE NOTICE 'Успешно создано 25 заказов!';
|
||
END $$;
|