440 lines
16 KiB
PL/PgSQL
440 lines
16 KiB
PL/PgSQL
create table restaurantes (
|
|
id uuid primary key default gen_random_uuid(),
|
|
nombre text not null,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
|
|
create table categorias (
|
|
id uuid primary key default gen_random_uuid(),
|
|
nombre text not null,
|
|
restaurante_id uuid references restaurantes,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
create index categorias_restaurante_id on categorias (restaurante_id);
|
|
|
|
create table zonas_produccion (
|
|
id uuid primary key default gen_random_uuid(),
|
|
nombre text not null,
|
|
restaurante_id uuid references restaurantes,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
|
|
);
|
|
create index zonas_produccion_restaurante_id on zonas_produccion (restaurante_id);
|
|
|
|
create table usuarios (
|
|
id uuid primary key default gen_random_uuid(),
|
|
auth0_id text not null,
|
|
nombre text not null
|
|
);
|
|
|
|
create table usuarios_restaurantes (
|
|
usuario_id uuid references usuarios,
|
|
restaurante_id uuid references restaurantes,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp,
|
|
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,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
create index productores_usuario_id on productores (usuario_id);
|
|
create index productores_zona_produccion_id on productores (zona_produccion_id);
|
|
|
|
create table recaudadores (
|
|
id uuid primary key default gen_random_uuid(),
|
|
usuario_id uuid references usuarios,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
create index recaudadores_usuario_id on recaudadores (usuario_id);
|
|
|
|
create table meseros (
|
|
id uuid primary key default gen_random_uuid(),
|
|
usuario_id uuid references usuarios,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
create index meseros_usuario_id on meseros (usuario_id);
|
|
|
|
create table administradores (
|
|
id uuid primary key default gen_random_uuid(),
|
|
usuario_id uuid references usuarios,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
create index administradores_usuario_id on administradores (usuario_id);
|
|
|
|
create table ingredientes (
|
|
id uuid primary key default gen_random_uuid(),
|
|
nombre text not null,
|
|
medida text not null,
|
|
restaurante_id uuid references restaurantes,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
create index ingredientes_restaurante_id on ingredientes (restaurante_id);
|
|
|
|
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,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
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 table recetas (
|
|
producto_id uuid references productos,
|
|
ingrediente_id uuid references ingredientes,
|
|
unidades numeric not null,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp,
|
|
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,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
create index proveedores_restaurante_id on proveedores (restaurante_id);
|
|
|
|
create table compras (
|
|
id uuid primary key default gen_random_uuid(),
|
|
fecha_compra date not null,
|
|
proveedor_id uuid references proveedores,
|
|
restaurante_id uuid references restaurantes,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
create index compras_proveedor_id on compras (proveedor_id);
|
|
create index compras_restaurante_id on compras (restaurante_id);
|
|
|
|
create table facturas (
|
|
id uuid primary key default gen_random_uuid(),
|
|
numero text not null,
|
|
monto_bruto bigint not null,
|
|
iva bigint not null default 0,
|
|
ila bigint not null default 0,
|
|
monto_neto bigint not null,
|
|
fecha_emision date not null,
|
|
fecha_vencimiento date not null,
|
|
compra_id uuid references compras,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
create index facturas_compra_id on facturas (compra_id);
|
|
|
|
create table compra_ingredientes (
|
|
id uuid primary key default gen_random_uuid(),
|
|
unidades numeric not null,
|
|
monto_unitario_bruto bigint not null,
|
|
iva bigint not null default 0,
|
|
ila bigint not null default 0,
|
|
monto_unitario_neto bigint not null,
|
|
compra_id uuid references compras,
|
|
ingrediente_id uuid references ingredientes,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
create index compra_ingredientes_compra_id on compra_ingredientes (compra_id);
|
|
create index compra_ingredientes_ingrediente_id on compra_ingredientes (ingrediente_id);
|
|
|
|
create table sectores (
|
|
id uuid primary key default gen_random_uuid(),
|
|
nombre text not null,
|
|
restaurante_id uuid references restaurantes,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
create index sectores_restaurante_id on sectores (restaurante_id);
|
|
|
|
create table tipos_canal (
|
|
id uuid primary key default gen_random_uuid(),
|
|
nombre text not null,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
|
|
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,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
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 table ventas (
|
|
id uuid primary key default gen_random_uuid(),
|
|
tiempo_venta timestamptz,
|
|
mesero_id uuid references meseros,
|
|
canal_id uuid references canales_venta,
|
|
restaurante_id uuid references restaurantes,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
create index ventas_mesero_id on ventas (mesero_id);
|
|
create index ventas_canal_id on ventas (canal_id);
|
|
create index ventas_restaurante_id on ventas (restaurante_id);
|
|
|
|
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,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
create index boletas_electronicas_venta_id on boletas_electronicas (venta_id);
|
|
create index boletas_electronicas_restaurante_id on boletas_electronicas (restaurante_id);
|
|
|
|
create table boletas_exentas (
|
|
id uuid primary key default gen_random_uuid(),
|
|
venta_id uuid references ventas,
|
|
restaurante_id uuid references restaurantes,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
create index boletas_exentas_venta_id on boletas_exentas (venta_id);
|
|
create index boletas_exentas_restaurante_id on boletas_exentas (restaurante_id);
|
|
|
|
create table estados_produccion (
|
|
id uuid primary key default gen_random_uuid(),
|
|
nombre text not null,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
|
|
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,
|
|
inserted_at timestamptz not null default current_timestamp,
|
|
updated_at timestamptz not null default current_timestamp
|
|
);
|
|
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);
|
|
|
|
------------------------------------
|
|
--- Triggers para update
|
|
------------------------------------
|
|
|
|
CREATE OR REPLACE FUNCTION trigger_set_timestamp()
|
|
RETURNS TRIGGER AS
|
|
$$
|
|
BEGIN
|
|
NEW.updated_at = current_timestamp;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
create trigger trigger_update_restaurantes
|
|
before update
|
|
on restaurantes
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_categorias
|
|
before update
|
|
on categorias
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_zonas_produccion
|
|
before update
|
|
on zonas_produccion
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_usuarios
|
|
before update
|
|
on usuarios
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_usuarios_restaurantes
|
|
before update
|
|
on usuarios_restaurantes
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_productores
|
|
before update
|
|
on productores
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_recaudadores
|
|
before update
|
|
on recaudadores
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_meseros
|
|
before update
|
|
on meseros
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_administradores
|
|
before update
|
|
on administradores
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_ingredientes
|
|
before update
|
|
on ingredientes
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_productos
|
|
before update
|
|
on productos
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_recetas
|
|
before update
|
|
on recetas
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_proveedores
|
|
before update
|
|
on proveedores
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_compras
|
|
before update
|
|
on compras
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_facturas
|
|
before update
|
|
on facturas
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_compra_ingredientes
|
|
before update
|
|
on compra_ingredientes
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_sectores
|
|
before update
|
|
on sectores
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_tipos_canal
|
|
before update
|
|
on tipos_canal
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_canales_venta
|
|
before update
|
|
on canales_venta
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_ventas
|
|
before update
|
|
on ventas
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_boletas_electronicas
|
|
before update
|
|
on boletas_electronicas
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_boletas_exentas
|
|
before update
|
|
on boletas_exentas
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_estados_produccion
|
|
before update
|
|
on estados_produccion
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
create trigger trigger_update_venta_productos
|
|
before update
|
|
on venta_productos
|
|
for each row
|
|
execute procedure trigger_set_timestamp();
|
|
|
|
------------------------------------
|
|
--- Views para crear la bodega
|
|
------------------------------------
|
|
|
|
--- View para obtener la lista de egresos de bodega
|
|
create view bodega_egresos as
|
|
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;
|
|
|
|
--- View para obtener la lista de ingresos a bodega
|
|
create view bodega_ingresos as
|
|
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;
|
|
|
|
--- 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;
|