CREATE TABLE contacto_emergencia(id_contacto SERIAL UNIQUE, telefono_emergencia BIGINT NOT NULL CHECK (telefono_emergencia > 99999999 AND telefono_emergencia < 100000000000), nombre_emergencia VARCHAR(50) NOT NULL, PRIMARY KEY (id_contacto) ); CREATE TABLE enfermedad(id_enfermedad SMALLSERIAL UNIQUE, descripcion_enfermedad TEXT NOT NULL, PRIMARY KEY (id_enfermedad) ); CREATE TABLE empresa(rut_empresa VARCHAR(9) NOT NULL UNIQUE, nombre_empresa VARCHAR(50) NOT NULL, contacto VARCHAR(50) NOT NULL, telefono BIGINT NOT NULL CHECK (telefono > 99999999 AND telefono < 100000000000), PRIMARY KEY (rut_empresa) ); CREATE TABLE especialidad(id_especialidad SMALLSERIAL UNIQUE, descripcion_especialidad TEXT NOT NULL, PRIMARY KEY (id_especialidad) ); CREATE TABLE categoria(id_categoria SMALLSERIAL UNIQUE, descripcion_categoria TEXT NOT NULL, PRIMARY KEY (id_categoria) ); CREATE TABLE vehiculo(patente VARCHAR(6) NOT NULL UNIQUE, ano_vehiculo SMALLINT NOT NULL, marca VARCHAR(20) NOT NULL, capacidad SMALLINT NOT NULL, PRIMARY KEY (patente) ); CREATE TABLE region(id_region SMALLSERIAL UNIQUE, nombre_region VARCHAR(20) NOT NULL, PRIMARY KEY (id_region) ); CREATE TABLE ciudad(id_ciudad SMALLSERIAL UNIQUE, nombre_ciudad VARCHAR(20) NOT NULL, id_region SMALLINT, PRIMARY KEY (id_ciudad), FOREIGN KEY (id_region) REFERENCES region (id_region) ON DELETE CASCADE ); CREATE TABLE guia(rut_guia VARCHAR(9) NOT NULL UNIQUE, nombre_guia VARCHAR(50) NOT NULL, calle VARCHAR(20) NOT NULL, numero SMALLINT NOT NULL, id_ciudad SMALLINT, PRIMARY KEY (rut_guia), FOREIGN KEY (id_ciudad) REFERENCES ciudad (id_ciudad) ON DELETE CASCADE ); CREATE TABLE tour(id_tour SERIAL UNIQUE, nombre_tour VARCHAR(50) NOT NULL, costo_indiv INT NOT NULL CHECK (costo_indiv > costo_grupal), costo_grupal INT NOT NULL CHECK (costo_grupal > 0), minima_personas INT NOT NULL CHECK (minima_personas > 0), id_ciudad SMALLINT, PRIMARY KEY (id_tour), FOREIGN KEY (id_ciudad) REFERENCES ciudad (id_ciudad) ON DELETE CASCADE ); CREATE TABLE lugar(id_lugar SMALLSERIAL UNIQUE, nombre_lugar VARCHAR(50) NOT NULL, valor_entrada INT NOT NULL CHECK (valor_entrada >= 0), nivel SMALLINT NOT NULL CHECK (nivel >= 0), id_ciudad SMALLINT, PRIMARY KEY (id_lugar), FOREIGN KEY (id_ciudad) REFERENCES ciudad (id_ciudad) ON DELETE CASCADE ); CREATE TABLE turista(rut_turista VARCHAR(9) NOT NULL UNIQUE, nombre_turista VARCHAR(50) NOT NULL, fecha_nacimento DATE NOT NULL, id_contacto INT, PRIMARY KEY (rut_turista), FOREIGN KEY (id_contacto) REFERENCES contacto_emergencia (id_contacto) ON DELETE CASCADE ); CREATE TABLE tiene_enfermedad(rut_turista VARCHAR(9) NOT NULL, id_enfermedad SMALLINT NOT NULL, FOREIGN KEY (rut_turista) REFERENCES turista (rut_turista) ON DELETE CASCADE, FOREIGN KEY (id_enfermedad) REFERENCES enfermedad (id_enfermedad) ON DELETE CASCADE ); CREATE TABLE descuento(id_descuento SMALLSERIAL UNIQUE, descripcion_descuento TEXT NOT NULL, porcentaje DECIMAL(3,2) NOT NULL CHECK (porcentaje BETWEEN 0 AND 1), PRIMARY KEY (id_descuento) ); CREATE TABLE realiza(id_tour INT NOT NULL, rut_turista VARCHAR(9) NOT NULL, id_descuento SMALLINT NOT NULL, FOREIGN KEY (id_tour) REFERENCES tour (id_tour) ON DELETE CASCADE, FOREIGN KEY (rut_turista) REFERENCES turista (rut_turista) ON DELETE CASCADE, FOREIGN KEY (id_descuento) REFERENCES descuento (id_descuento) ON DELETE CASCADE ); CREATE TABLE arrienda(patente VARCHAR(6) NOT NULL, rut_empresa VARCHAR(9) NOT NULL, precio INT NOT NULL CHECK (precio > 0), fecha_devolucion DATE NOT NULL, FOREIGN KEY (patente) REFERENCES vehiculo (patente) ON DELETE CASCADE, FOREIGN KEY (rut_empresa) REFERENCES empresa (rut_empresa) ON DELETE CASCADE ); CREATE TABLE posee(rut_guia VARCHAR(9) NOT NULL, id_especialidad SMALLINT NOT NULL, nivel_especialidad SMALLINT NOT NULL CHECK (nivel_especialidad >= 0), FOREIGN KEY (rut_guia) REFERENCES guia (rut_guia) ON DELETE CASCADE, FOREIGN KEY (id_especialidad) REFERENCES especialidad (id_especialidad) ON DELETE CASCADE ); CREATE TABLE participa(id_tour INT NOT NULL, rut_guia VARCHAR(9) NOT NULL, id_categoria SMALLINT NOT NULL, FOREIGN KEY (id_tour) REFERENCES tour (id_tour) ON DELETE CASCADE, FOREIGN KEY (rut_guia) REFERENCES guia (rut_guia) ON DELETE CASCADE, FOREIGN KEY (id_categoria) REFERENCES categoria (id_categoria) ON DELETE CASCADE ); CREATE TABLE asociado(id_tour INT NOT NULL, id_lugar SMALLINT NOT NULL, fecha_llegada DATE, hora_llegada TIME, fecha_salida DATE, hora_salida TIME, FOREIGN KEY (id_tour) REFERENCES tour (id_tour) ON DELETE CASCADE, FOREIGN KEY (id_lugar) REFERENCES lugar (id_lugar) ON DELETE CASCADE ); CREATE TABLE requerir_auto(id_tour INT NOT NULL, patente VARCHAR(6) NOT NULL, chofer VARCHAR(50) NOT NULL, FOREIGN KEY (id_tour) REFERENCES tour (id_tour) ON DELETE CASCADE, FOREIGN KEY (patente) REFERENCES vehiculo (patente) ON DELETE CASCADE );