Add operations & node_type check triggers
This commit is contained in:
parent
04d3c775f8
commit
0120de27bf
9 changed files with 204 additions and 19 deletions
|
@ -10,4 +10,6 @@ DROP TABLE images;
|
||||||
DROP TABLE meal_images;
|
DROP TABLE meal_images;
|
||||||
|
|
||||||
DROP TYPE node_type;
|
DROP TYPE node_type;
|
||||||
|
DROP FUNCTION check_node_type();
|
||||||
|
DROP FUNCTION check_linked_restaurants();
|
||||||
DROP EXTENSION postgis CASCADE;
|
DROP EXTENSION postgis CASCADE;
|
||||||
|
|
|
@ -4,17 +4,53 @@ CREATE EXTENSION postgis;
|
||||||
CREATE TABLE nodes(
|
CREATE TABLE nodes(
|
||||||
id SERIAL PRIMARY KEY,
|
id SERIAL PRIMARY KEY,
|
||||||
name VARCHAR(100) NOT NULL,
|
name VARCHAR(100) NOT NULL,
|
||||||
type NODE_TYPE NOT NULL,
|
node_type NODE_TYPE NOT NULL,
|
||||||
coordinates GEOMETRY(POINT,4326) NOT NULL
|
coordinates GEOMETRY(POINT,4326) NOT NULL
|
||||||
);
|
);
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION check_linked_restaurants()
|
||||||
|
RETURNS TRIGGER AS $$
|
||||||
|
BEGIN
|
||||||
|
-- Check if the node is being updated from 'restaurant' to a different type
|
||||||
|
IF OLD.node_type = 'restaurant' AND NEW.node_type <> 'restaurant' THEN
|
||||||
|
-- Check if the node still has linked restaurants
|
||||||
|
IF EXISTS (SELECT 1 FROM restaurants WHERE node_id = OLD.id) THEN
|
||||||
|
RAISE EXCEPTION 'Cannot change node type from "restaurant" as it still has linked restaurants';
|
||||||
|
END IF;
|
||||||
|
END IF;
|
||||||
|
RETURN NEW;
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
CREATE TRIGGER check_linked_restaurants_trigger
|
||||||
|
BEFORE UPDATE OF node_type ON nodes
|
||||||
|
FOR EACH ROW
|
||||||
|
EXECUTE FUNCTION check_linked_restaurants();
|
||||||
|
|
||||||
|
|
||||||
CREATE TABLE restaurants(
|
CREATE TABLE restaurants(
|
||||||
id SERIAL PRIMARY KEY,
|
id SERIAL PRIMARY KEY,
|
||||||
node_id INTEGER REFERENCES nodes(id) NOT NULL,
|
node_id INTEGER REFERENCES nodes(id) NOT NULL,
|
||||||
address VARCHAR(30) NOT NULL,
|
address VARCHAR(30) NOT NULL,
|
||||||
price INTEGER CHECK ( price >= 0 AND price <= 10 ) NOT NULL
|
price SMALLINT CHECK ( price >= 0 AND price <= 10 ) NOT NULL
|
||||||
);
|
);
|
||||||
|
|
||||||
|
CREATE FUNCTION check_node_type()
|
||||||
|
RETURNS TRIGGER AS $$
|
||||||
|
BEGIN
|
||||||
|
-- Check if the node referenced by the foreign key is of type 'restaurant'
|
||||||
|
IF (SELECT node_type FROM nodes WHERE id = NEW.node_id) <> 'restaurant' THEN
|
||||||
|
RAISE EXCEPTION 'The referenced node has not type "restaurant"';
|
||||||
|
END IF;
|
||||||
|
RETURN NEW;
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
CREATE TRIGGER enforce_node_type
|
||||||
|
BEFORE INSERT OR UPDATE ON restaurants
|
||||||
|
FOR EACH ROW
|
||||||
|
EXECUTE FUNCTION check_node_type();
|
||||||
|
|
||||||
CREATE TABLE images(
|
CREATE TABLE images(
|
||||||
id SERIAL PRIMARY KEY,
|
id SERIAL PRIMARY KEY,
|
||||||
url VARCHAR(50) NOT NULL
|
url VARCHAR(50) NOT NULL
|
||||||
|
@ -41,7 +77,7 @@ CREATE TABLE meals(
|
||||||
restaurant_rating_id INTEGER REFERENCES restaurant_ratings(id) NOT NULL,
|
restaurant_rating_id INTEGER REFERENCES restaurant_ratings(id) NOT NULL,
|
||||||
user_id INTEGER REFERENCES users(id) NOT NULL,
|
user_id INTEGER REFERENCES users(id) NOT NULL,
|
||||||
name VARCHAR(30) NOT NULL,
|
name VARCHAR(30) NOT NULL,
|
||||||
rating INTEGER CHECK ( rating >= 0 AND rating <= 10 ) NOT NULL,
|
rating SMALLINT CHECK ( rating >= 0 AND rating <= 10 ) NOT NULL,
|
||||||
price DECIMAL(12,2) CHECK (price >= 0) NOT NULL,
|
price DECIMAL(12,2) CHECK (price >= 0) NOT NULL,
|
||||||
price_currency VARCHAR(1) CHECK (TRIM(price_currency) <> '') NOT NULL,
|
price_currency VARCHAR(1) CHECK (TRIM(price_currency) <> '') NOT NULL,
|
||||||
note VARCHAR(100) NOT NULL DEFAULT '',
|
note VARCHAR(100) NOT NULL DEFAULT '',
|
||||||
|
|
|
@ -1,6 +1,21 @@
|
||||||
--- src/full_schema.rs 2024-05-10 11:34:46.376360145 +0200
|
--- src/full_schema.rs 2024-05-10 22:44:39.336282167 +0200
|
||||||
+++ src/schema.rs 2024-05-10 11:34:24.009031704 +0200
|
+++ src/schema.rs 2024-05-10 22:45:22.991271745 +0200
|
||||||
@@ -52,13 +52,12 @@
|
@@ -1,14 +1,10 @@
|
||||||
|
// @generated automatically by Diesel CLI.
|
||||||
|
|
||||||
|
pub mod sql_types {
|
||||||
|
#[derive(diesel::query_builder::QueryId, diesel::sql_types::SqlType)]
|
||||||
|
- #[diesel(postgres_type(name = "geometry"))]
|
||||||
|
- pub struct Geometry;
|
||||||
|
-
|
||||||
|
- #[derive(diesel::query_builder::QueryId, diesel::sql_types::SqlType)]
|
||||||
|
#[diesel(postgres_type(name = "node_type"))]
|
||||||
|
pub struct NodeType;
|
||||||
|
}
|
||||||
|
|
||||||
|
diesel::table! {
|
||||||
|
use diesel::sql_types::*;
|
||||||
|
@@ -52,13 +48,12 @@
|
||||||
}
|
}
|
||||||
|
|
||||||
diesel::table! {
|
diesel::table! {
|
||||||
|
@ -13,4 +28,4 @@
|
||||||
id -> Int4,
|
id -> Int4,
|
||||||
#[max_length = 100]
|
#[max_length = 100]
|
||||||
name -> Varchar,
|
name -> Varchar,
|
||||||
#[sql_name = "type"]
|
node_type -> NodeType,
|
||||||
|
|
|
@ -3,7 +3,12 @@ extern crate diesel;
|
||||||
|
|
||||||
mod db;
|
mod db;
|
||||||
mod models;
|
mod models;
|
||||||
|
mod ops;
|
||||||
mod schema;
|
mod schema;
|
||||||
use diesel::prelude::*;
|
|
||||||
|
|
||||||
fn main() {}
|
fn main() {
|
||||||
|
ops::node_ops::create_node();
|
||||||
|
ops::restaurant_ops::create_restaurant();
|
||||||
|
// ops::node_ops::update_node();
|
||||||
|
ops::node_ops::show_nodes();
|
||||||
|
}
|
||||||
|
|
|
@ -1,4 +1,4 @@
|
||||||
use crate::schema::nodes;
|
use crate::schema::{nodes, restaurants};
|
||||||
use diesel::prelude::*;
|
use diesel::prelude::*;
|
||||||
use postgis_diesel::types::Point;
|
use postgis_diesel::types::Point;
|
||||||
|
|
||||||
|
@ -13,6 +13,30 @@ pub enum NodeType {
|
||||||
#[diesel(table_name = nodes)]
|
#[diesel(table_name = nodes)]
|
||||||
pub struct NewNode<'a> {
|
pub struct NewNode<'a> {
|
||||||
pub name: &'a str,
|
pub name: &'a str,
|
||||||
pub type_: NodeType,
|
pub node_type: NodeType,
|
||||||
pub coordinates: Point,
|
pub coordinates: Point,
|
||||||
}
|
}
|
||||||
|
|
||||||
|
#[derive(Debug, Queryable, AsChangeset)]
|
||||||
|
pub struct Node {
|
||||||
|
pub id: i32,
|
||||||
|
pub name: String,
|
||||||
|
pub node_type: NodeType,
|
||||||
|
pub coordinates: Point,
|
||||||
|
}
|
||||||
|
|
||||||
|
#[derive(Insertable)]
|
||||||
|
#[diesel(table_name = restaurants)]
|
||||||
|
pub struct NewRestaurant<'a> {
|
||||||
|
pub node_id: i32,
|
||||||
|
pub address: &'a str,
|
||||||
|
pub price: i16,
|
||||||
|
}
|
||||||
|
|
||||||
|
#[derive(Debug, Queryable, AsChangeset)]
|
||||||
|
pub struct Restaurant {
|
||||||
|
pub id: i32,
|
||||||
|
pub node_id: i32,
|
||||||
|
pub address: String,
|
||||||
|
pub price: i16,
|
||||||
|
}
|
||||||
|
|
2
src/ops.rs
Normal file
2
src/ops.rs
Normal file
|
@ -0,0 +1,2 @@
|
||||||
|
pub mod node_ops;
|
||||||
|
pub mod restaurant_ops;
|
55
src/ops/node_ops.rs
Normal file
55
src/ops/node_ops.rs
Normal file
|
@ -0,0 +1,55 @@
|
||||||
|
use crate::db::establish_connection;
|
||||||
|
use crate::models::*;
|
||||||
|
use diesel::prelude::*;
|
||||||
|
|
||||||
|
pub fn create_node() {
|
||||||
|
use crate::schema::nodes::dsl::*;
|
||||||
|
|
||||||
|
let mut conn = establish_connection();
|
||||||
|
|
||||||
|
let new_node = NewNode {
|
||||||
|
name: "Foo",
|
||||||
|
node_type: NodeType::Restaurant,
|
||||||
|
coordinates: postgis_diesel::types::Point {
|
||||||
|
x: 0.0,
|
||||||
|
y: 0.0,
|
||||||
|
srid: Some(4326),
|
||||||
|
},
|
||||||
|
};
|
||||||
|
|
||||||
|
diesel::insert_into(nodes)
|
||||||
|
.values(&new_node)
|
||||||
|
.execute(&mut conn)
|
||||||
|
.expect("Error saving new Node");
|
||||||
|
}
|
||||||
|
|
||||||
|
pub fn update_node() {
|
||||||
|
use crate::schema::nodes::dsl::*;
|
||||||
|
|
||||||
|
let node_id = 1;
|
||||||
|
let mut conn = establish_connection();
|
||||||
|
|
||||||
|
let node = Node {
|
||||||
|
id: node_id,
|
||||||
|
name: "Bar".to_string(),
|
||||||
|
node_type: NodeType::Marker,
|
||||||
|
coordinates: postgis_diesel::types::Point {
|
||||||
|
x: 6.9,
|
||||||
|
y: 0.0,
|
||||||
|
srid: Some(4326),
|
||||||
|
},
|
||||||
|
};
|
||||||
|
|
||||||
|
diesel::update(nodes.find(node_id))
|
||||||
|
.set(&node)
|
||||||
|
.execute(&mut conn)
|
||||||
|
.expect("Error saving new Node");
|
||||||
|
}
|
||||||
|
|
||||||
|
pub fn show_nodes() {
|
||||||
|
use crate::schema::nodes::dsl::*;
|
||||||
|
|
||||||
|
let mut conn = establish_connection();
|
||||||
|
let results = nodes.load::<Node>(&mut conn).expect("Error loading Nodes");
|
||||||
|
println!("{:?}", results);
|
||||||
|
}
|
51
src/ops/restaurant_ops.rs
Normal file
51
src/ops/restaurant_ops.rs
Normal file
|
@ -0,0 +1,51 @@
|
||||||
|
use crate::db::establish_connection;
|
||||||
|
use crate::models::*;
|
||||||
|
use diesel::prelude::*;
|
||||||
|
|
||||||
|
pub fn create_restaurant() {
|
||||||
|
use crate::schema::restaurants::dsl::*;
|
||||||
|
|
||||||
|
let mut conn = establish_connection();
|
||||||
|
|
||||||
|
let new_node = NewRestaurant {
|
||||||
|
node_id: 1,
|
||||||
|
address: "Hauptstraße 8",
|
||||||
|
price: 1,
|
||||||
|
};
|
||||||
|
|
||||||
|
diesel::insert_into(restaurants)
|
||||||
|
.values(&new_node)
|
||||||
|
.execute(&mut conn)
|
||||||
|
.expect("Error saving new Node");
|
||||||
|
}
|
||||||
|
|
||||||
|
// pub fn update_node() {
|
||||||
|
// use crate::schema::nodes::dsl::*;
|
||||||
|
//
|
||||||
|
// let node_id = 1;
|
||||||
|
// let mut conn = establish_connection();
|
||||||
|
//
|
||||||
|
// let node = Node {
|
||||||
|
// id: node_id,
|
||||||
|
// name: "Bar".to_string(),
|
||||||
|
// type_: NodeType::Restaurant,
|
||||||
|
// coordinates: postgis_diesel::types::Point {
|
||||||
|
// x: 6.9,
|
||||||
|
// y: 0.0,
|
||||||
|
// srid: Some(4326),
|
||||||
|
// },
|
||||||
|
// };
|
||||||
|
//
|
||||||
|
// diesel::update(nodes.find(node_id))
|
||||||
|
// .set(&node)
|
||||||
|
// .execute(&mut conn)
|
||||||
|
// .expect("Error saving new Node");
|
||||||
|
// }
|
||||||
|
//
|
||||||
|
// pub fn show_nodes() {
|
||||||
|
// use crate::schema::nodes::dsl::*;
|
||||||
|
//
|
||||||
|
// let mut conn = establish_connection();
|
||||||
|
// let results = nodes.load::<Node>(&mut conn).expect("Error loading Nodes");
|
||||||
|
// println!("{:?}", results);
|
||||||
|
// }
|
|
@ -1,10 +1,6 @@
|
||||||
// @generated automatically by Diesel CLI.
|
// @generated automatically by Diesel CLI.
|
||||||
|
|
||||||
pub mod sql_types {
|
pub mod sql_types {
|
||||||
#[derive(diesel::query_builder::QueryId, diesel::sql_types::SqlType)]
|
|
||||||
#[diesel(postgres_type(name = "geometry"))]
|
|
||||||
pub struct Geometry;
|
|
||||||
|
|
||||||
#[derive(diesel::query_builder::QueryId, diesel::sql_types::SqlType)]
|
#[derive(diesel::query_builder::QueryId, diesel::sql_types::SqlType)]
|
||||||
#[diesel(postgres_type(name = "node_type"))]
|
#[diesel(postgres_type(name = "node_type"))]
|
||||||
pub struct NodeType;
|
pub struct NodeType;
|
||||||
|
@ -41,7 +37,7 @@ diesel::table! {
|
||||||
user_id -> Int4,
|
user_id -> Int4,
|
||||||
#[max_length = 30]
|
#[max_length = 30]
|
||||||
name -> Varchar,
|
name -> Varchar,
|
||||||
rating -> Int4,
|
rating -> Int2,
|
||||||
price -> Numeric,
|
price -> Numeric,
|
||||||
#[max_length = 1]
|
#[max_length = 1]
|
||||||
price_currency -> Varchar,
|
price_currency -> Varchar,
|
||||||
|
@ -60,8 +56,7 @@ diesel::table! {
|
||||||
id -> Int4,
|
id -> Int4,
|
||||||
#[max_length = 100]
|
#[max_length = 100]
|
||||||
name -> Varchar,
|
name -> Varchar,
|
||||||
#[sql_name = "type"]
|
node_type -> NodeType,
|
||||||
type_ -> NodeType,
|
|
||||||
coordinates -> Geometry,
|
coordinates -> Geometry,
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
@ -88,7 +83,7 @@ diesel::table! {
|
||||||
node_id -> Int4,
|
node_id -> Int4,
|
||||||
#[max_length = 30]
|
#[max_length = 30]
|
||||||
address -> Varchar,
|
address -> Varchar,
|
||||||
price -> Int4,
|
price -> Int2,
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
|
|
Loading…
Reference in a new issue