Skip to content

Commit

Permalink
Update API docs and Solution docs
Browse files Browse the repository at this point in the history
  • Loading branch information
bkuberek committed Aug 5, 2024
1 parent 494c271 commit 2222738
Show file tree
Hide file tree
Showing 2 changed files with 107 additions and 50 deletions.
41 changes: 32 additions & 9 deletions docs/api.md
Original file line number Diff line number Diff line change
@@ -1,14 +1,20 @@
# Bookings API

Visit the GraphQL UI at http://localhost:8080/q/graphql-ui/
Visit the GraphQL UI at http://localhost:8080/q/graphql-ui/.
You can access the complete API documentation there.

Below are some examples. You can also see more examples in

- [src/test/kotlin/com/bkuberek/bookings/graphql/v1](https://github.com/bkuberek/kotlin-quarkus-booking-service-demo/tree/main/src/test/kotlin/com/bkuberek/bookings/graphql/v1)
- [src/test/resources/graphql](https://github.com/bkuberek/kotlin-quarkus-booking-service-demo/tree/main/src/test/resources/graphql)

## Get a list of all restaurants

Query

```graphql
query AllRestaurants {
restaurants: restaurants {
restaurants: allRestaurants {
id
name
endorsements
Expand All @@ -18,6 +24,7 @@ query AllRestaurants {
}
}
}

```

Variables
Expand All @@ -31,23 +38,32 @@ Variables
Query

```graphql
query FindTables(
query FindTable(
$time: DateTime!,
$size: Int!,
$restrictions: [Endorsement]!,
$endorsements: [Endorsement]!,
) {
restaurants: findTable(
time: $time,
size: $size,
restrictions: $restrictions
endorsements: $endorsements
) {
id
name
size
endorsements
tables {
size
quantity
}
occupiedTables {
size
quantity
}
availableTables {
size
quantity
}
}
}
```
Expand All @@ -57,7 +73,7 @@ Variables
```json
{
"size": 2,
"restrictions": ["gluten"],
"endorsements": ["gluten"],
"time": "2024-08-01T20:00:00.00Z"
}
```
Expand Down Expand Up @@ -180,6 +196,7 @@ Variables
"name": "Tobias"
}
```
Optional parameter: `restaurantId: UUID`, return reservations for a single restaurant.

## Delete a Reservation

Expand All @@ -188,9 +205,15 @@ Mutation
```graphql
mutation DeleteReservation($id: String!) {
reservation: deleteReservation(id: $id) {
name
size
reservationTime
... on ReservationInfo {
name
size
reservationTime
}
... on ReservationError {
error
message
}
}
}
```
Expand Down
116 changes: 75 additions & 41 deletions docs/solution.md
Original file line number Diff line number Diff line change
Expand Up @@ -18,13 +18,26 @@ We need to implement at a minimum, 3 endpoints,

### Data

#### User Input for finding a restaurant
#### User Input

for finding a restaurant,

- Name
- Group Size
- Dietary Restrictions
- Reservation Time

for creating a reservation,

- Name
- Group Size
- Reservation Time
- Restaurant Id

for deleting a reservation,

- Reservation Id

#### Storage

Given scope and scale, a relational database such as PostgreSQL is appropriate.
Expand All @@ -33,37 +46,54 @@ We need tables to represent the different entities and their relationships.
#### Tables

Since the scope does not include authentication and user management, we can exclude that from the data model and provide
user preferences as parameters to the endpoints. Therefore, we have the following entities.
user preferences as parameters to the endpoints.

A Restaurant has both Tables and Endorsements. A Reservation has Tables.
We don't need to know the Endorsements of a Reservation since it is used to match a restaurant and we can get that from the Restaurant.
We don't need to know the Endorsements of a Reservation since it is used to find a restaurant.
When creating a reservation, we have already selected the venue based on endorsements.

- restaurant
- restaurant endorsement
- restaurant table
- reservation
- reservation table

---

## Solution

GraphQL API written in Kotlin using the Quarkus framework and the PostgresSQL database.

The reasoning is that GraphQL offers a lot more flexibility and makes building complex APIs much easier than with REST.
The Quarkus framework is probably the best available for Java today, and Kotlin being newer and fun, why not?!

Unless the requirements specifically ask for something else, PostgresSQL is a great choice for data persistence.
Also, this seems to be a problem that requires complex SQL queries in order to aggregate total, occupied and available
capacity for restaurants.

## Data Model

Since this service does not implement authentication, there was no need to have a user table.
User's name and Restrictions are provided during booking of tables.
User's name and Restrictions are provided as parameters during booking of tables.

![database diagram](database.png)

## SQL

Some of the SQL is inline in the DAO and some are included from the resources folder.
In some cases, the SQL is templated using [stringtemplate4](https://github.com/antlr/stringtemplate4/blob/master/doc/templates.md).
[Cheatsheet](https://github.com/antlr/stringtemplate4/blob/master/doc/cheatsheet.md).
Some of the SQL is inline in
the [DAO](https://github.com/bkuberek/kotlin-quarkus-booking-service-demo/blob/main/src/main/kotlin/com/bkuberek/bookings/db/dao/)
and some are included from
the [resources folder](https://github.com/bkuberek/kotlin-quarkus-booking-service-demo/tree/main/src/main/resources/com/bkuberek/bookings/db/dao/RestaurantDao).
In some cases, the SQL is templated
using [stringtemplate4](https://github.com/antlr/stringtemplate4/blob/master/doc/templates.md), [Cheatsheet](https://github.com/antlr/stringtemplate4/blob/master/doc/cheatsheet.md).

Originally, this project began using Hibernate ORM and Panache. However, that made it nearly impossible to write custom sql queries.
[The switch](https://github.com/bkuberek/kotlin-quarkus-booking-service-demo/pull/1) to [Quarkus-Jdbi](https://github.com/quarkiverse/quarkus-jdbi) made all the difference in completing this project.
> Originally, this project began using Hibernate ORM and Panache. However, that made it nearly impossible to write
> custom sql queries.
[The switch](https://github.com/bkuberek/kotlin-quarkus-booking-service-demo/pull/1)
> to [Quarkus-Jdbi](https://github.com/quarkiverse/quarkus-jdbi) made all the difference in completing this project.
Below are some example queries. The API uses a combination of these queries. Refer to the links above to review the
actual SQL used in the app.

### Total Restaurant Capacity

Expand Down Expand Up @@ -99,7 +129,7 @@ ORDER BY 2, 3;
| d42c8608-7d52-4ea3-823f-c59b68a33407 | u.to.pi.a | 4 | 0 | 0 |
| d42c8608-7d52-4ea3-823f-c59b68a33407 | u.to.pi.a | 6 | 0 | 0 |

Filter results by dietary restrictions
### Filter results by dietary restrictions

```postgresql
SELECT r.id,
Expand All @@ -124,7 +154,7 @@ ORDER BY 2, 3;
| d42c8608-7d52-4ea3-823f-c59b68a33407 | u.to.pi.a | 4 | 0 | 0 |
| d42c8608-7d52-4ea3-823f-c59b68a33407 | u.to.pi.a | 6 | 0 | 0 |

Restaurant Capacity by table size
### Restaurant Capacity by table size

```postgresql
SELECT sub.id,
Expand Down Expand Up @@ -162,7 +192,8 @@ ORDER BY 2, 3;
| d42c8608-7d52-4ea3-823f-c59b68a33407 | u.to.pi.a | {vegan,vegetarian} | 4 | 0 | 0 |
| d42c8608-7d52-4ea3-823f-c59b68a33407 | u.to.pi.a | {vegan,vegetarian} | 6 | 0 | 0 |

This query lists restaurants, their endorsements and total capacity.
### Restaurants, their endorsements and total capacity.

In this case total capacity is the number of people the venue can accommodate.

```postgresql
Expand All @@ -189,25 +220,26 @@ ORDER BY total_capacity;
| b1e6728c-da7c-4841-bbf3-ba7e97f7e07c | Tetetlán | {gluten,paleo} | 26 |
| c52e1d11-757a-48dc-88e8-4bf9866ca53a | Falling Piano Brewing Co | {} | 60 |

## Find Reserved Capacity
## Finding Reserved Capacity

We have determined that a reservation lasts 2 hours. We are looking for how many tables are booked within 2 hours prior
of TIME.
These are tables that are still in use.
We have determined that a reservation lasts 2 hours.
We are looking for how many reservations will begin or end during the 2 hours of the requested time.
These are tables that are still in use. We can use this number to subtract from the total number of tables and we get
availability.

List of restaurant IDs and their current booked capacity between (TIME - 2 hours) and TIME.

```postgresql
-- INPUT TIME: 2024-08-03 21:00:00.000000 +00:00
-- Looking between (TIME - 2) and TIME
SELECT b.restaurant_id,
bt.size,
SUM(bt.quantity) as occupied
FROM reservation AS b
INNER JOIN restaurant AS r ON b.restaurant_id = r.id
INNER JOIN reservation_table AS bt ON bt.reservation_id = b.id
WHERE b.reservation_time > '2024-08-03 19:00:00.000000 +00:00'
AND b.reservation_time <= '2024-08-03 21:00:00.000000 +00:00'
WHERE (b.reservation_time >= :time_start
AND :time_stop > b.reservation_time)
OR (b.reservation_time + INTERVAL '2 hours' >= :time_start
AND :time_stop > b.reservation_time + INTERVAL '2 hours')
GROUP BY 1, 2;
```

Expand All @@ -232,13 +264,13 @@ Also check in the future that the table capacity is still available.

```sql
-- Existing reservation starts within `time_start` and `time_stop`
(b.reservation_time >= :time_start AND b.reservation_time < :time_stop)
OR
(b.reservation_time >= :time_start AND b.reservation_time < :time_stop)
OR
-- Existing reservation + `INTERVAL` is between `time_start` and `time_stop`
(b.reservation_time + INTERVAL :time_interval >= :time_start AND b.reservation_time + INTERVAL :time_interval < :time_stop)
```

**Update:** this is the current implementation.
> **Update:** this is the current implementation.
## Find Available Capacity

Expand All @@ -257,8 +289,10 @@ WITH venue AS (SELECT r.id,
FROM reservation AS b
INNER JOIN restaurant AS r ON b.restaurant_id = r.id
INNER JOIN reservation_table AS bt ON bt.reservation_id = b.id
WHERE b.reservation_time >= '2024-08-04 19:00:00.000000 +00:00'
AND b.reservation_time < '2024-08-04 21:00:00.000000 +00:00'
WHERE (b.reservation_time >= :time_start
AND :time_stop > b.reservation_time)
OR (b.reservation_time + INTERVAL '2 hours' >= :time_start
AND :time_stop > b.reservation_time + INTERVAL '2 hours')
GROUP BY 1, 2)
SELECT venue.id,
Expand Down Expand Up @@ -298,26 +332,23 @@ WITH venue AS (SELECT r.id,
SUM(rt.quantity) as capacity
FROM restaurant AS r
INNER JOIN restaurant_table AS rt ON rt.restaurant_id = r.id
WHERE r.id = :restaurant_id
GROUP BY 1, 2),
endorsing AS (SELECT r.id,
re.endorsement
FROM restaurant AS r
INNER JOIN restaurant_endorsement AS re ON re.restaurant_id = r.id
WHERE r.id = :restaurant_id
WHERE re.endorsement IN ('gluten')
GROUP BY 1, 2),
booked AS (SELECT b.restaurant_id AS id,
bt.size,
SUM(bt.quantity) as occupied
FROM reservation AS b
INNER JOIN restaurant AS r ON b.restaurant_id = r.id
INNER JOIN reservation_table AS bt ON bt.reservation_id = b.id
WHERE r.id = :restaurant_id
AND (
(b.reservation_time >= :time_start AND b.reservation_time < :time_stop)
OR (b.reservation_time + INTERVAL :time_interval >= :time_start AND
b.reservation_time + INTERVAL :time_interval < :time_stop)
)
WHERE (b.reservation_time >= :time_start
AND :time_stop > b.reservation_time)
OR (b.reservation_time + INTERVAL '2 hours' >= :time_start
AND :time_stop > b.reservation_time + INTERVAL '2 hours')
GROUP BY 1, 2)
SELECT sub.id,
Expand All @@ -327,7 +358,7 @@ SELECT sub.id,
sub.occupied,
sub.available,
sub.available_seats,
ARRAY_REMOVE(ARRAY_AGG(endorsing.endorsement), NULL) as endorsements
ARRAY_AGG(endorsing.endorsement) as endorsements
FROM (SELECT venue.id,
venue.size,
COALESCE(venue.capacity, 0) AS total,
Expand All @@ -337,18 +368,21 @@ FROM (SELECT venue.id,
FROM venue
LEFT JOIN booked on (booked.id = venue.id AND booked.size = venue.size)) as sub
INNER JOIN restaurant as rr ON rr.id = sub.id
LEFT JOIN endorsing on endorsing.id = sub.id
INNER JOIN endorsing on endorsing.id = sub.id
WHERE sub.available_seats >= :size
AND sub.id = :restaurant_id
GROUP BY 1, 2, 3, 4, 5, 6, 7
ORDER BY 2, 3
;
```

| id | name | size | total | occupied | available | available\_seats | endorsements |
|:-------------------------------------|:------|:-----|:------|:---------|:----------|:-----------------|:-------------|
| 635dc3bd-c515-4d41-848b-bc487bb13810 | Lardo | 2 | 4 | 0 | 4 | 8 | {gluten} |
| 635dc3bd-c515-4d41-848b-bc487bb13810 | Lardo | 4 | 2 | 0 | 2 | 8 | {gluten} |
| id | name | size | total | occupied | available | available\_seats | endorsements |
|:-------------------------------------|:------------------|:-----|:------|:---------|:----------|:-----------------|:-------------|
| 635dc3bd-c515-4d41-848b-bc487bb13810 | Lardo | 2 | 4 | 0 | 4 | 8 | {gluten} |
| 635dc3bd-c515-4d41-848b-bc487bb13810 | Lardo | 4 | 2 | 0 | 2 | 8 | {gluten} |
| dfe2cab1-6a39-4426-8937-c1d89403e0f0 | Panadería Rosetta | 2 | 3 | 0 | 3 | 6 | {gluten} |
| dfe2cab1-6a39-4426-8937-c1d89403e0f0 | Panadería Rosetta | 4 | 2 | 1 | 1 | 4 | {gluten} |
| b1e6728c-da7c-4841-bbf3-ba7e97f7e07c | Tetetlán | 2 | 2 | 0 | 2 | 4 | {gluten} |
| b1e6728c-da7c-4841-bbf3-ba7e97f7e07c | Tetetlán | 4 | 4 | 0 | 4 | 16 | {gluten} |
| b1e6728c-da7c-4841-bbf3-ba7e97f7e07c | Tetetlán | 6 | 1 | 0 | 1 | 6 | {gluten} |

---

Expand Down

0 comments on commit 2222738

Please sign in to comment.