|
| 1 | +package com.hoangtien2k3.ticketbookingapi.entity; |
| 2 | + |
| 3 | +import com.hoangtien2k3.ticketbookingapi.model.ResponseCinema; |
| 4 | +import com.hoangtien2k3.ticketbookingapi.model.ResponseFormat; |
| 5 | +import com.hoangtien2k3.ticketbookingapi.model.ResponseScheduleCinema; |
| 6 | +import com.hoangtien2k3.ticketbookingapi.model.ResponseScheduleTime; |
| 7 | +import jakarta.persistence.*; |
| 8 | +import lombok.AllArgsConstructor; |
| 9 | +import lombok.Getter; |
| 10 | +import lombok.NoArgsConstructor; |
| 11 | +import lombok.Setter; |
| 12 | + |
| 13 | + |
| 14 | +@SqlResultSetMappings({ |
| 15 | + @SqlResultSetMapping( |
| 16 | + name = "ResponseScheduleTime", |
| 17 | + classes = @ConstructorResult( |
| 18 | + targetClass = ResponseScheduleTime.class, |
| 19 | + columns = { |
| 20 | + @ColumnResult(name = "schedule_id", type = Integer.class), |
| 21 | + @ColumnResult(name = "schedule_start", type = String.class) |
| 22 | + } |
| 23 | + ) |
| 24 | + ), |
| 25 | + @SqlResultSetMapping( |
| 26 | + name = "ResponseFormat", |
| 27 | + classes = @ConstructorResult( |
| 28 | + targetClass = ResponseFormat.class, |
| 29 | + columns = { |
| 30 | + @ColumnResult(name = "movie_format") |
| 31 | + } |
| 32 | + ) |
| 33 | + ), |
| 34 | + @SqlResultSetMapping( |
| 35 | + name = "ResponseCinema", |
| 36 | + classes = @ConstructorResult( |
| 37 | + targetClass = ResponseCinema.class, |
| 38 | + columns = { |
| 39 | + @ColumnResult(name = "cinema_id"), |
| 40 | + @ColumnResult(name = "cinema_name"), |
| 41 | + @ColumnResult(name = "cinema_address") |
| 42 | + } |
| 43 | + ) |
| 44 | + ), |
| 45 | + @SqlResultSetMapping( |
| 46 | + name = "showSchedule", |
| 47 | + classes = @ConstructorResult( |
| 48 | + targetClass = ResponseScheduleCinema.class, |
| 49 | + columns = { |
| 50 | + @ColumnResult(name = "cinema_id"), |
| 51 | + @ColumnResult(name = "cinema_name"), |
| 52 | + @ColumnResult(name = "cinema_data", type = String.class) |
| 53 | + } |
| 54 | + ) |
| 55 | + ) |
| 56 | +}) |
| 57 | + |
| 58 | +/* |
| 59 | + SELECT |
| 60 | + schedule.schedule_id, schedule.schedule_start |
| 61 | + FROM |
| 62 | + movies, schedule, room, cinemas |
| 63 | + WHERE |
| 64 | + movies.movie_id = schedule.movie_id |
| 65 | + AND schedule.room_id = room.room_id |
| 66 | + AND room.cinema_id = cinemas.cinema_id |
| 67 | + AND movies.movie_id = ?1 |
| 68 | + AND schedule.schedule_date = ?2 |
| 69 | + AND cinemas.cinema_id = ?3 |
| 70 | +*/ |
| 71 | +@NamedNativeQuery(name = "getScheduleTimeByFilm", resultSetMapping = "ResponseScheduleTime", |
| 72 | + query = "SELECT `schedule`.`schedule_id`, `schedule`.`schedule_start` " + |
| 73 | + "FROM `movies`,`schedule`,`room`,`cinemas` " + |
| 74 | + "WHERE `movies`.`movie_id` = `schedule`.`movie_id` AND `schedule`.`room_id` = `room`.`room_id`AND `room`.`cinema_id` = `cinemas`.`cinema_id` AND `movies`.`movie_id` = ?1 AND `schedule`.`schedule_date` = ?2 AND `cinemas`.`cinema_id` = ?3" |
| 75 | +) |
| 76 | + |
| 77 | +/* |
| 78 | + SELECT |
| 79 | + movies.movie_format |
| 80 | + FROM |
| 81 | + movies, schedule, room, cinemas |
| 82 | + WHERE |
| 83 | + movies.movie_id = schedule.movie_id |
| 84 | + AND schedule.room_id = room.room_id |
| 85 | + AND room.cinema_id = cinemas.cinema_id |
| 86 | + AND movies.movie_id = ?1 |
| 87 | + AND schedule.schedule_date = ?2 |
| 88 | + AND cinemas.cinema_id = ?3 |
| 89 | + GROUP BY |
| 90 | + movies.movie_format |
| 91 | +*/ |
| 92 | +@NamedNativeQuery(name = "getScheduleFormat", resultSetMapping = "ResponseFormat", |
| 93 | + query = "SELECT `movies`.`movie_format` " + |
| 94 | + "FROM `movies`,`schedule`,`room`,`cinemas` " + |
| 95 | + "WHERE `movies`.`movie_id` = `schedule`.`movie_id` AND `schedule`.`room_id` = `room`.`room_id`AND `room`.`cinema_id` = `cinemas`.`cinema_id` AND `movies`.`movie_id` = ?1 AND `schedule`.`schedule_date` = ?2 AND `cinemas`.`cinema_id` = ?3 " + |
| 96 | + "GROUP BY `movies`.`movie_format`" |
| 97 | +) |
| 98 | + |
| 99 | +/* |
| 100 | + SELECT |
| 101 | + cinemas.* |
| 102 | + FROM |
| 103 | + cinemas, |
| 104 | + schedule, |
| 105 | + room |
| 106 | + WHERE |
| 107 | + schedule.room_id = room.room_id |
| 108 | + AND room.cinema_id = cinemas.cinema_id |
| 109 | + AND schedule.movie_id = ?1 |
| 110 | + AND schedule.schedule_date = ?2 |
| 111 | +*/ |
| 112 | +@NamedNativeQuery(name = "getResponseCinema", resultSetMapping = "ResponseCinema", |
| 113 | + query = "SELECT `cinemas`.* " + |
| 114 | + "FROM `cinemas`, `schedule`, `room` " + |
| 115 | + "WHERE `schedule`.`room_id` = `room`.`room_id` AND `room`.`cinema_id` = `cinemas`.`cinema_id` AND `schedule`.`movie_id` = ?1 AND `schedule`.`schedule_date` = ?2" |
| 116 | +) |
| 117 | + |
| 118 | +/* |
| 119 | + SELECT |
| 120 | + d.cinema_id, |
| 121 | + d.cinema_name, |
| 122 | + JSON_ARRAYAGG( |
| 123 | + JSON_OBJECT( |
| 124 | + 'schedule_id', d.schedule_id, |
| 125 | + 'schedule_start', TIME_FORMAT(schedule_start, '%H:%i'), |
| 126 | + 'seat_empty', d.seatempty |
| 127 | + ) |
| 128 | + ) as cinema_data |
| 129 | + FROM ( |
| 130 | + SELECT |
| 131 | + sdl.schedule_id, |
| 132 | + sdl.schedule_start, |
| 133 | + cinemas.cinema_id, |
| 134 | + cinemas.cinema_name, |
| 135 | + ( |
| 136 | + SELECT |
| 137 | + COUNT(seats.seat_id) |
| 138 | + FROM |
| 139 | + seats |
| 140 | + WHERE |
| 141 | + seats.room_id = room.room_id |
| 142 | + AND seats.seat_id NOT IN ( |
| 143 | + SELECT |
| 144 | + booking.seat_id |
| 145 | + FROM |
| 146 | + booking |
| 147 | + WHERE |
| 148 | + booking.schedule_id = sdl.schedule_id |
| 149 | + ) |
| 150 | + ) as seatempty |
| 151 | + FROM |
| 152 | + schedule sdl |
| 153 | + INNER JOIN room room ON sdl.room_id = room.room_id |
| 154 | + INNER JOIN cinemas cinemas ON cinemas.cinema_id = room.cinema_id |
| 155 | + WHERE |
| 156 | + sdl.movie_id = ?1 |
| 157 | + AND sdl.schedule_date = ?2 |
| 158 | + ) d |
| 159 | + GROUP BY |
| 160 | + d.cinema_id, |
| 161 | + d.cinema_name |
| 162 | +*/ |
| 163 | +@NamedNativeQuery(name = "showSchedule", resultSetMapping = "showSchedule", |
| 164 | + query = "SELECT d.cinema_id, d.cinema_name, (JSON_ARRAYAGG(JSON_OBJECT('schedule_id', d.schedule_id, 'schedule_start', TIME_FORMAT(schedule_start, '%H:%i'), 'seat_empty', d.seatempty))) as cinema_data " + |
| 165 | + "FROM ( " + |
| 166 | + "SELECT sdl.schedule_id, sdl.schedule_start, cinemas.cinema_id, cinemas.cinema_name, (SELECT COUNT(seats.seat_id) slots FROM seats seats WHERE seats.room_id = room.room_id AND seats.seat_id NOT IN (SELECT booking.seat_id FROM booking booking WHERE booking.schedule_id = sdl.schedule_id)) as seatempty FROM schedule sdl INNER JOIN room room ON sdl.room_id = room.room_id INNER JOIN cinemas cinemas ON cinemas.cinema_id = room.cinema_id WHERE sdl.movie_id = ?1 AND sdl.schedule_date = ?2) d " + |
| 167 | + "GROUP BY d.cinema_id, d.cinema_name" |
| 168 | +) |
| 169 | + |
| 170 | +@Setter |
| 171 | +@Getter |
| 172 | +@NoArgsConstructor |
| 173 | +@AllArgsConstructor |
| 174 | +@Entity |
| 175 | +@Table(name = "schedule") |
| 176 | +public class Schedule { |
| 177 | + @Id |
| 178 | + @GeneratedValue(strategy = GenerationType.AUTO) |
| 179 | + @Column(name = "schedule_id") |
| 180 | + private int scheduleId; |
| 181 | + |
| 182 | + @Column(name = "movie_id") |
| 183 | + private int movieId; |
| 184 | + |
| 185 | + @Column(name = "room_id") |
| 186 | + private int roomId; |
| 187 | + |
| 188 | + @Column(name = "schedule_date") |
| 189 | + private String scheduleDate; |
| 190 | + |
| 191 | + @Column(name = "schedule_start") |
| 192 | + private String scheduleStart; |
| 193 | + |
| 194 | + @Column(name = "schedule_end") |
| 195 | + private String scheduleEnd; |
| 196 | +} |
0 commit comments