Files
unified-restaurant-original/database/init/00-schema.sql
2021-07-20 23:55:49 -04:00

479 lines
18 KiB
PL/PgSQL

start transaction;
drop view if exists bodega_egresos cascade;
drop view if exists bodega_ingresos cascade;
drop view if exists bodega_movimientos cascade;
drop view if exists bodega_actual cascade;
drop table if exists usuarios_restaurantes cascade;
drop table if exists productores cascade;
drop table if exists recetas cascade;
drop table if exists facturas cascade;
drop table if exists compra_ingredientes cascade;
drop table if exists ingredientes cascade;
drop table if exists compras cascade;
drop table if exists proveedores cascade;
drop table if exists efectivos cascade;
drop table if exists boletas_electronicas cascade;
drop table if exists boletas_exentas cascade;
drop table if exists venta_productos cascade;
drop table if exists productos cascade;
drop table if exists categorias cascade;
drop table if exists zonas_produccion cascade;
drop table if exists ventas cascade;
drop table if exists usuarios cascade;
drop table if exists canales_venta cascade;
drop table if exists sectores cascade;
drop table if exists restaurantes cascade;
drop table if exists tipos_canal cascade;
drop table if exists medios_pago cascade;
drop table if exists cajas cascade;
drop table if exists estados_produccion cascade;
create table restaurantes
(
id uuid primary key default gen_random_uuid(),
nombre text not null,
created_at timestamptz not null default current_timestamp,
updated_at timestamptz not null default current_timestamp,
deleted_at timestamptz
);
create table categorias
(
id uuid primary key default gen_random_uuid(),
nombre text not null,
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 zonas_produccion
(
id uuid primary key default gen_random_uuid(),
nombre text not null,
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 usuarios
(
id uuid primary key default gen_random_uuid(),
auth0_id text not null,
nombre text not null,
created_at timestamptz not null default current_timestamp,
updated_at timestamptz not null default current_timestamp,
deleted_at timestamptz
);
create table usuarios_restaurantes
(
usuario_id uuid references usuarios,
restaurante_id uuid references restaurantes,
created_at timestamptz not null default current_timestamp,
updated_at timestamptz not null default current_timestamp,
deleted_at timestamptz,
primary key (usuario_id, restaurante_id)
);
create table productores
(
id uuid primary key default gen_random_uuid(),
usuario_id uuid references usuarios,
zona_produccion_id uuid references zonas_produccion,
created_at timestamptz not null default current_timestamp,
updated_at timestamptz not null default current_timestamp,
deleted_at timestamptz
);
create table ingredientes
(
id uuid primary key default gen_random_uuid(),
nombre text not null,
medida text not null,
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 productos
(
id uuid primary key default gen_random_uuid(),
nombre text not null,
precio_venta bigint not null,
categoria_id uuid references categorias,
zona_produccion_id uuid references zonas_produccion,
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 recetas
(
id uuid primary key default gen_random_uuid(),
producto_id uuid references productos,
ingrediente_id uuid references ingredientes,
unidades numeric not null,
created_at timestamptz not null default current_timestamp,
updated_at timestamptz not null default current_timestamp,
deleted_at timestamptz,
primary key (producto_id, ingrediente_id)
);
create table proveedores
(
id uuid primary key default gen_random_uuid(),
rut text not null,
nombre text not null,
descripcion text not null,
direccion text null,
telefono text null,
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 compras
(
id uuid primary key default gen_random_uuid(),
fecha_compra date not null,
en_arqueo bool not null default true,
proveedor_id uuid references proveedores,
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 facturas
(
id uuid primary key default gen_random_uuid(),
numero text not null,
monto_bruto bigint not null,
compra_id uuid references compras,
created_at timestamptz not null default current_timestamp,
updated_at timestamptz not null default current_timestamp,
deleted_at timestamptz
);
create table compra_ingredientes
(
id uuid primary key default gen_random_uuid(),
unidades numeric not null,
monto_unitario bigint not null,
compra_id uuid references compras,
ingrediente_id uuid references ingredientes,
created_at timestamptz not null default current_timestamp,
updated_at timestamptz not null default current_timestamp,
deleted_at timestamptz
);
create table sectores
(
id uuid primary key default gen_random_uuid(),
nombre text not null,
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 tipos_canal
(
id uuid primary key default gen_random_uuid(),
nombre text not null,
created_at timestamptz not null default current_timestamp,
updated_at timestamptz not null default current_timestamp,
deleted_at timestamptz
);
create table canales_venta
(
id uuid primary key default gen_random_uuid(),
nombre text not null,
sector_id uuid references sectores,
tipo_canal_id uuid references tipos_canal,
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 medios_pago
(
id uuid primary key default gen_random_uuid(),
nombre text not null,
created_at timestamptz not null default current_timestamp,
updated_at timestamptz not null default current_timestamp,
deleted_at timestamptz
);
create table cajas
(
id uuid primary key default gen_random_uuid(),
fondo bigint not null,
apertura timestamptz not null,
cierre timestamptz,
created_at timestamptz not null default current_timestamp,
updated_at timestamptz not null default current_timestamp,
deleted_at timestamptz
);
create table efectivos
(
id uuid primary key default gen_random_uuid(),
veinte_mil bigint not null,
diez_mil bigint not null,
cinco_mil bigint not null,
dos_mil bigint not null,
mil bigint not null,
quinientos bigint not null,
cien bigint not null,
cincuenta bigint not null,
diez bigint not null,
caja_id uuid references cajas,
created_at timestamptz not null default current_timestamp,
updated_at timestamptz not null default current_timestamp,
deleted_at timestamptz
);
create table ventas
(
id uuid primary key default gen_random_uuid(),
tiempo_venta timestamptz,
usuario_id uuid references usuarios,
canal_id uuid references canales_venta,
restaurante_id uuid references restaurantes,
medio_pago_id uuid references medios_pago,
caja_id uuid references cajas,
created_at timestamptz not null default current_timestamp,
updated_at timestamptz not null default current_timestamp,
deleted_at timestamptz
);
create table boletas_electronicas
(
id uuid primary key default gen_random_uuid(),
numero_boleta text not null,
venta_id uuid references ventas,
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 boletas_exentas
(
id uuid primary key default gen_random_uuid(),
venta_id uuid references ventas,
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 estados_produccion
(
id uuid primary key default gen_random_uuid(),
nombre text not null,
created_at timestamptz not null default current_timestamp,
updated_at timestamptz not null default current_timestamp,
deleted_at timestamptz
);
create table venta_productos
(
id uuid primary key default gen_random_uuid(),
tiempo_entrada timestamptz not null,
tiempo_salida timestamptz null,
venta_id uuid references ventas,
producto_id uuid references productos,
estado_id uuid references estados_produccion,
created_at timestamptz not null default current_timestamp,
updated_at timestamptz not null default current_timestamp,
deleted_at timestamptz
);
create table bodega_egresos
(
unidades numeric not null,
fecha timestamptz not null,
ingrediente_id uuid not null,
restaurante_id uuid not null,
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 not null,
restaurante_id uuid not null,
created_at timestamptz not null default current_timestamp,
updated_at timestamptz not null default current_timestamp,
deleted_at timestamptz
);
------------------------------------
--- Indexes para todas las referencias
------------------------------------
create index categorias_restaurante_id on categorias (restaurante_id);
create index zonas_produccion_restaurante_id on zonas_produccion (restaurante_id);
create index productores_usuario_id on productores (usuario_id);
create index productores_zona_produccion_id on productores (zona_produccion_id);
create index ingredientes_restaurante_id on ingredientes (restaurante_id);
create index productos_categoria_id on productos (categoria_id);
create index productos_zona_produccion_id on productos (zona_produccion_id);
create index productos_restaurante_id on productos (restaurante_id);
create index proveedores_restaurante_id on proveedores (restaurante_id);
create index compras_proveedor_id on compras (proveedor_id);
create index compras_restaurante_id on compras (restaurante_id);
create index facturas_compra_id on facturas (compra_id);
create index compra_ingredientes_compra_id on compra_ingredientes (compra_id);
create index compra_ingredientes_ingrediente_id on compra_ingredientes (ingrediente_id);
create index sectores_restaurante_id on sectores (restaurante_id);
create index canales_venta_sector_id on canales_venta (sector_id);
create index canales_venta_tipo_canal_id on canales_venta (tipo_canal_id);
create index canales_venta_restaurante_id on canales_venta (restaurante_id);
create index ventas_canal_id on ventas (canal_id);
create index ventas_usuario_id on ventas (usuario_id);
create index ventas_restaurante_id on ventas (restaurante_id);
create index boletas_electronicas_venta_id on boletas_electronicas (venta_id);
create index boletas_electronicas_restaurante_id on boletas_electronicas (restaurante_id);
create index boletas_exentas_venta_id on boletas_exentas (venta_id);
create index boletas_exentas_restaurante_id on boletas_exentas (restaurante_id);
create index venta_productos_venta_id on venta_productos (venta_id);
create index venta_productos_producto_id on venta_productos (producto_id);
create index venta_productos_estado_id on venta_productos (estado_id);
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);
------------------------------------
--- Triggers para poblar la bodega
------------------------------------
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();
------------------------------------
--- Views para crear la bodega
------------------------------------
--- 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;