144 lines
5.1 KiB
PL/PgSQL
144 lines
5.1 KiB
PL/PgSQL
start transaction;
|
|
|
|
drop view bodega_actual cascade;
|
|
drop view bodega_movimientos cascade;
|
|
drop view bodega_egresos cascade;
|
|
drop view bodega_ingresos cascade;
|
|
|
|
create table bodega_egresos
|
|
(
|
|
unidades numeric not null,
|
|
fecha timestamptz not null,
|
|
ingrediente_id uuid references ingredientes,
|
|
restaurante_id uuid references restaurantes,
|
|
created_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp,
|
|
deleted_at timestamptz
|
|
);
|
|
|
|
create table bodega_ingresos
|
|
(
|
|
unidades numeric not null,
|
|
fecha timestamptz not null,
|
|
ingrediente_id uuid references ingredientes,
|
|
restaurante_id uuid references restaurantes,
|
|
created_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp,
|
|
deleted_at timestamptz
|
|
);
|
|
|
|
create index bodega_egresos_ingrediente_id on bodega_egresos (ingrediente_id);
|
|
create index bodega_egresos_restaurante_id on bodega_egresos (restaurante_id);
|
|
create index bodega_ingresos_ingrediente_id on bodega_ingresos (ingrediente_id);
|
|
create index bodega_ingresos_restaurante_id on bodega_ingresos (restaurante_id);
|
|
|
|
create or replace function bodega_egresos_trigger_insert_procedure() returns trigger
|
|
language PLPGSQL as
|
|
$$
|
|
BEGIN
|
|
insert into bodega_egresos (ingrediente_id, unidades, fecha, restaurante_id)
|
|
select recetas.ingrediente_id as ingrediente_id,
|
|
recetas.unidades as unidades,
|
|
date(venta_productos.tiempo_entrada) as fecha,
|
|
ventas.restaurante_id as restaurante_id
|
|
from ventas
|
|
join venta_productos on ventas.id = venta_productos.venta_id
|
|
join productos on venta_productos.producto_id = productos.id
|
|
join recetas on productos.id = recetas.producto_id
|
|
where venta_productos.id = NEW.id;
|
|
RETURN null;
|
|
END;
|
|
$$;
|
|
|
|
create or replace function bodega_egresos_trigger_delete_procedure()
|
|
returns trigger
|
|
language PLPGSQL as
|
|
$$
|
|
BEGIN
|
|
insert into bodega_egresos (ingrediente_id, unidades, fecha, restaurante_id)
|
|
select recetas.ingrediente_id as ingrediente_id,
|
|
recetas.unidades * -1 as unidades,
|
|
date(venta_productos.tiempo_entrada) as fecha,
|
|
ventas.restaurante_id as restaurante_id
|
|
from ventas
|
|
join venta_productos on ventas.id = venta_productos.venta_id
|
|
join productos on venta_productos.producto_id = productos.id
|
|
join recetas on productos.id = recetas.producto_id
|
|
where venta_productos.id = OLD.id;
|
|
RETURN null;
|
|
END;
|
|
$$;
|
|
|
|
create or replace function bodega_ingresos_trigger_insert_procedure()
|
|
returns trigger
|
|
language PLPGSQL as
|
|
$$
|
|
BEGIN
|
|
insert into bodega_ingresos (ingrediente_id, unidades, fecha, restaurante_id)
|
|
select compra_ingredientes.ingrediente_id as ingrediente_id,
|
|
compra_ingredientes.unidades as unidades,
|
|
compras.fecha_compra as fecha,
|
|
compras.restaurante_id as restaurante_id
|
|
from compras
|
|
join compra_ingredientes on compras.id = compra_ingredientes.compra_id
|
|
where compra_ingredientes.id = NEW.id;
|
|
RETURN null;
|
|
END;
|
|
$$;
|
|
|
|
create or replace function bodega_ingresos_trigger_delete_procedure()
|
|
returns trigger
|
|
language PLPGSQL as
|
|
$$
|
|
BEGIN
|
|
insert into bodega_ingresos (ingrediente_id, unidades, fecha, restaurante_id)
|
|
select compra_ingredientes.ingrediente_id as ingrediente_id,
|
|
compra_ingredientes.unidades * -1 as unidades,
|
|
compras.fecha_compra as fecha,
|
|
compras.restaurante_id as restaurante_id
|
|
from compras
|
|
join compra_ingredientes on compras.id = compra_ingredientes.compra_id
|
|
where compra_ingredientes.id = OLD.id;
|
|
RETURN null;
|
|
END;
|
|
$$;
|
|
|
|
create trigger bodega_egresos_insert_trigger
|
|
after insert
|
|
on venta_productos
|
|
for each row
|
|
execute procedure bodega_egresos_trigger_insert_procedure();
|
|
|
|
create trigger bodega_egresos_delete_trigger
|
|
after update of deleted_at
|
|
on venta_productos
|
|
for each row
|
|
execute procedure bodega_egresos_trigger_delete_procedure();
|
|
|
|
create trigger bodega_ingresos_insert_trigger
|
|
after insert
|
|
on compra_ingredientes
|
|
for each row
|
|
execute procedure bodega_ingresos_trigger_insert_procedure();
|
|
|
|
create trigger bodega_ingresos_delete_trigger
|
|
after update of deleted_at
|
|
on compra_ingredientes
|
|
for each row
|
|
execute procedure bodega_ingresos_trigger_delete_procedure();
|
|
|
|
--- View que une el estado de bodega en una sola tabla
|
|
create view bodega_movimientos as
|
|
select ingrediente_id, unidades * -1 as unidades, fecha, restaurante_id
|
|
from bodega_egresos
|
|
union all
|
|
select ingrediente_id, unidades, fecha, restaurante_id
|
|
from bodega_ingresos;
|
|
|
|
--- View que muestra el estado actual de la bodega por cada ingrediente
|
|
create view bodega_actual as
|
|
select ingrediente_id as ingrediente_id, sum(unidades) as stock, restaurante_id as restaurante_id
|
|
from bodega_movimientos
|
|
group by bodega_movimientos.ingrediente_id, bodega_movimientos.restaurante_id;
|
|
|
|
commit; |