Skip to content

Roads Update #29

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Closed
wants to merge 2 commits into from
Closed
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
102 changes: 102 additions & 0 deletions sql/schema.README.md
Original file line number Diff line number Diff line change
Expand Up @@ -17,6 +17,7 @@ This document provides an overview of the database schema for **Infrastructure M
- [📍 Poles](#-poles)
- [🚪 Gates](#-gates)
- [🌍 Land Use Areas](#-land-use-areas)
- [🛣️ Roads](#️-roads)

---

Expand Down Expand Up @@ -453,3 +454,104 @@ erDiagram
- **`landuse_area_type`**: Defines types of land use areas (e.g., residential, agricultural).
- **`landuse_area_owner`**: Represents owners of land use areas.
- **`landuse_area`**: Represents individual land use areas with geometry and metadata.

---

## 🛣️ Roads

This section describes roads, their segments, connecting points, type, construction/usage status, surface material, and conditions.

```mermaid
erDiagram
segment_type {
SERIAL id PK
UUID uuid UNIQUE
TIMESTAMP last_update
TEXT last_update_by
VARCHAR type_name UNIQUE
TEXT description
}

segment_status {
SERIAL id PK
UUID uuid UNIQUE
TIMESTAMP last_update
TEXT last_update_by
VARCHAR status_name UNIQUE
TEXT description
}

segment_surface {
SERIAL id PK
UUID uuid UNIQUE
TIMESTAMP last_update
TEXT last_update_by
VARCHAR surface_name UNIQUE
TEXT description
}

segment_condition {
SERIAL id PK
UUID uuid UNIQUE
TIMESTAMP last_update
TEXT last_update_by
VARCHAR condition_name UNIQUE
TEXT description
}

intersection {
SERIAL id PK
UUID uuid UNIQUE
TIMESTAMP last_update
TEXT last_update_by
GEOMETRY geom
}

road {
SERIAL id PK
UUID uuid UNIQUE
TIMESTAMP last_update
TEXT last_update_by
TEXT name
}

road_segment {
SERIAL id PK
UUID uuid UNIQUE
TIMESTAMP last_update
TEXT last_update_by
INT segment_number UNIQUE
INT lanes
FLOAT length_m
INT speed_limit_kmh
BOOLEAN one_way
GEOMETRY geom
UUID road_uuid FK
UUID type_uuid FK
UUID status_uuid FK
UUID surface_uuid FK
UUID condition_uuid FK
UUID start_node FK
UUID end_node FK
}

segment_type ||--o{ road_segment : "defines type"
segment_status ||--o{ road_segment : "defines status"
segment_surface ||--o{ road_segment : "defines surface"
segment_condition ||--o{ road_segment : "defines condition"
intersection ||--o{ road_segment : "as start node"
intersection ||--o{ road_segment : "as end node"
road ||--o{ road_segment : "has segments"
```

***Explanation***

- **`segment_type`**: Defines the classification of road segments (e.g., National, Main Road, Gravel Road).
- **`segment_status`**: Describes the current status of road segments (e.g., In Use, Planned, Under Construction).
- **`segment_surface`**: Specifies the surface material of road segments (e.g., Asphalt, Gravel, Dirt).
- **`segment_condition`**: Records the current condition of road segments (e.g., Good, Poor, Flooded, Under Repair).
- **`intersection`**: Represents physical nodes (points) where road segments begin, end, or connect.
- **`road`**: Represents logical roads, typically composed of one or more connected road segments.
- **`road_segment`**: Represents physical sections of a road, linking two intersections and holding detailed metadata including type, status, surface, and condition.

---
13 changes: 5 additions & 8 deletions sql/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2160,7 +2160,7 @@ CREATE TABLE IF NOT EXISTS intersection(
uuid UUID UNIQUE NOT NULL DEFAULT gen_random_uuid(),
last_update TIMESTAMP DEFAULT now() NOT NULL,
last_update_by TEXT NOT NULL,
geom GEOMETRY(POINT, 32734) NOT NULL
geom GEOMETRY(POINT, 32734)
);
COMMENT ON TABLE intersection is 'Points between road segments.';

Expand All @@ -2181,7 +2181,6 @@ CREATE TABLE IF NOT EXISTS road(
last_update TIMESTAMP DEFAULT now() NOT NULL,
last_update_by TEXT NOT NULL,
name TEXT,
geom GEOMETRY(LINESTRING, 4326) NOT NULL
);
COMMENT ON TABLE road is 'Logical road entities, composed of road segments.';

Expand All @@ -2195,8 +2194,6 @@ COMMENT ON COLUMN road.last_update_by is 'The name of the user responsible for t

COMMENT ON COLUMN road.name is 'Road name information.';

COMMENT ON COLUMN road.geom is 'Approximate full geometry of the road. EPSG: 4326';

-- ROAD SEGMENTS
CREATE TABLE IF NOT EXISTS road_segment(
id SERIAL NOT NULL PRIMARY KEY,
Expand All @@ -2208,14 +2205,14 @@ CREATE TABLE IF NOT EXISTS road_segment(
length_m FLOAT CHECK (length_m > 0),
speed_limit_kmh INT CHECK (speed_limit_kmh > 0),
one_way BOOLEAN,
geom GEOMETRY(LINESTRING, 32734) NOT NULL,
road_uuid UUID NOT NULL REFERENCES road(uuid),
geom GEOMETRY(LINESTRING, 32734),
road_uuid UUID REFERENCES road(uuid),
type_uuid UUID NOT NULL REFERENCES segment_type(uuid),
status_uuid UUID NOT NULL REFERENCES segment_status(uuid),
surface_uuid UUID NOT NULL REFERENCES segment_surface(uuid),
condition_uuid UUID NOT NULL REFERENCES segment_condition(uuid),
start_node UUID NOT NULL REFERENCES intersection(uuid),
end_node UUID NOT NULL REFERENCES intersection(uuid)
start_node UUID REFERENCES intersection(uuid),
end_node UUID REFERENCES intersection(uuid)
);
COMMENT ON TABLE road_segment is 'Represents physical segments of a road between two nodes.';

Expand Down