Refactor: Update controllers and services for improved functionality and add new SQL queries

This commit is contained in:
grtsinry43 2025-05-22 20:39:59 +08:00
parent f4d8134fe5
commit e7b37c7891
Signed by: grtsinry43
GPG Key ID: F3305FB3A978C934
16 changed files with 11568 additions and 37 deletions

File diff suppressed because it is too large Load Diff

View File

@ -16,10 +16,7 @@ import org.springframework.web.bind.annotation.*;
import java.util.List;
/**
* <p>
* 前端控制器
* </p>
*
* 书籍控制器
* @author grtsinry43
* @since 2025-05-19
*/
@ -48,7 +45,6 @@ public class BookController {
}
@GetMapping("/search/title")
@AuthCheck(requiredRole = UserRole.USER)
public ApiResponse<PageResponse<List<BookVO>>> searchBooksByTitle(@RequestParam String title,
@RequestParam(defaultValue = "1") int pageNum,
@RequestParam(defaultValue = "10") int pageSize) {
@ -57,7 +53,6 @@ public class BookController {
}
@GetMapping("/search/author")
@AuthCheck(requiredRole = UserRole.USER)
public ApiResponse<PageResponse<List<BookVO>>> searchBooksByAuthor(@RequestParam String authorName,
@RequestParam(defaultValue = "1") int pageNum,
@RequestParam(defaultValue = "10") int pageSize) {
@ -66,7 +61,6 @@ public class BookController {
}
@GetMapping("/search/publisher")
@AuthCheck(requiredRole = UserRole.USER)
public ApiResponse<PageResponse<List<BookVO>>> searchBooksByPublisher(@RequestParam String publisherName,
@RequestParam(defaultValue = "1") int pageNum,
@RequestParam(defaultValue = "10") int pageSize) {

View File

@ -13,6 +13,12 @@ import org.springframework.web.bind.annotation.*;
import java.util.List;
/**
* 订单控制器
*
* @author grtsinry43
* @since 2025-05-19
*/
@RestController
@RequestMapping("/orders")
public class OrdersController {

View File

@ -9,9 +9,7 @@ import org.springframework.web.bind.annotation.*;
import java.util.List;
/**
* <p>
* 前端控制器
* </p>
* 出版社控制器
*
* @author grtsinry43
* @since 2025-05-19

View File

@ -11,6 +11,8 @@ import com.grtsinry43.bookmanagement.entity.Reader;
import com.grtsinry43.bookmanagement.service.ReaderService;
import com.grtsinry43.bookmanagement.util.JwtUtil;
import com.grtsinry43.bookmanagement.vo.ReaderVO;
import jakarta.servlet.http.HttpServletRequest;
import jakarta.servlet.http.HttpServletResponse;
import org.springframework.beans.BeanUtils;
import org.springframework.beans.factory.annotation.Autowired;
import org.springframework.web.bind.annotation.*;
@ -21,9 +23,7 @@ import java.util.Map;
import java.util.stream.Collectors;
/**
* <p>
* 前端控制器
* </p>
* 读者控制器
*
* @author grtsinry43
* @since 2025-05-19
@ -63,7 +63,7 @@ public class ReaderController {
@PostMapping("/login")
@AuthCheck(requiredRole = UserRole.NOT_LOGIN)
public ApiResponse<Map<String, Object>> login(@RequestBody LoginRequest loginRequest) {
public ApiResponse<ReaderVO> login(@RequestBody LoginRequest loginRequest, HttpServletResponse response) {
if (loginRequest.getUsername() == null || loginRequest.getPassword() == null ||
loginRequest.getUsername().trim().isEmpty() || loginRequest.getPassword().isEmpty()) {
throw new BusinessException(ErrorCode.PARAMS_ERROR);
@ -72,11 +72,9 @@ public class ReaderController {
Reader loggedInReader = readerService.login(loginRequest.getUsername(), loginRequest.getPassword());
String token = JwtUtil.generateToken(loggedInReader.getReaderId().toString());
Map<String, Object> responseData = new HashMap<>();
responseData.put("token", token);
responseData.put("user", convertToReaderVO(loggedInReader));
response.setHeader("Authorization", token);
return ApiResponse.success(responseData);
return ApiResponse.success(convertToReaderVO(loggedInReader));
}
@GetMapping("/admin/all")

View File

@ -139,6 +139,7 @@ public class BookServiceImpl extends ServiceImpl<BookMapper, Book> implements Bo
book1.setPublisherId(publisherId);
}
BeanUtils.copyProperties(book, book1);
book1.setAuthor(String.join(",", book.getAuthors()));
bookMapper.insert(book1);
resetBookAuthors(book1.getBookId(), book.getAuthors());
return buildBookVO(book1);

View File

@ -50,6 +50,7 @@ public class OrdersServiceImpl extends ServiceImpl<OrdersMapper, Orders> impleme
public OrderVO createOrder(OrderCreateDTO orderCreateDTO, Integer userId) {
Orders order = new Orders();
order.setOrderDate(LocalDateTime.now());
order.setReaderId(userId);
order.setStatus("PENDING");
BigDecimal totalAmount = BigDecimal.ZERO;
List<OrderItem> items = new ArrayList<>();

View File

@ -32,6 +32,7 @@ public class ReaderServiceImpl extends ServiceImpl<ReaderMapper, Reader> impleme
this.passwordEncoder = new BCryptPasswordEncoder();
}
@Override
public Reader getReaderById(Integer readerId) {
if (readerId == null) {

View File

@ -10,4 +10,4 @@ server.port=8080
mybatis.type-aliases-package=com.grtsinry43.bookmanagement.entity
mybatis.configuration.map-underscore-to-camel-case=true
logging.level.com.grtsinry43.bookmanagement.mapper=DEBUG
#logging.level.com.grtsinry43.bookmanagement.mapper=DEBUG

View File

@ -2,4 +2,38 @@
<!DOCTYPE mapper PUBLIC "-//mybatis.org//DTD Mapper 3.0//EN" "http://mybatis.org/dtd/mybatis-3-mapper.dtd">
<mapper namespace="com.grtsinry43.bookmanagement.mapper.AuthorMapper">
<!-- 1. 查询所有作者(单表+ORDER BY -->
<select id="findAllAuthors" resultType="com.grtsinry43.bookmanagement.entity.Author">
SELECT * FROM author ORDER BY name
</select>
<!-- 2. 查询名字包含关键字的作者(单表+LIKE -->
<select id="findByNameLike" resultType="com.grtsinry43.bookmanagement.entity.Author">
SELECT * FROM author WHERE name LIKE CONCAT('%', #{name}, '%')
</select>
<!-- 3. 查询每位作者的图书数量(连接+GROUP BY+COUNT -->
<select id="countBooksByAuthor" resultType="map">
SELECT a.author_id, a.name, COUNT(ba.book_id) AS book_count
FROM author a
LEFT JOIN book_author ba ON a.author_id = ba.author_id
GROUP BY a.author_id, a.name
ORDER BY book_count DESC
</select>
<!-- 4. 查询没有图书的作者嵌套NOT EXISTS -->
<select id="findAuthorsWithoutBooks" resultType="com.grtsinry43.bookmanagement.entity.Author">
SELECT * FROM author a WHERE NOT EXISTS (
SELECT 1 FROM book_author ba WHERE ba.author_id = a.author_id
)
</select>
<!-- 5. 查询指定一组ID的作者IN集合查询 -->
<select id="findByIds" resultType="com.grtsinry43.bookmanagement.entity.Author">
SELECT * FROM author WHERE author_id IN
<foreach collection="ids" item="id" open="(" separator="," close=")">
#{id}
</foreach>
</select>
</mapper>

View File

@ -3,47 +3,128 @@
<mapper namespace="com.grtsinry43.bookmanagement.mapper.BookMapper">
<select id="findById" resultType="com.grtsinry43.bookmanagement.entity.Book">
SELECT * FROM book WHERE book_id = #{bookId}
SELECT *
FROM book
WHERE book_id = #{bookId}
</select>
<select id="findAll" resultType="com.grtsinry43.bookmanagement.entity.Book">
SELECT * FROM book
SELECT *
FROM book
</select>
<select id="findByTitle" resultType="com.grtsinry43.bookmanagement.entity.Book">
SELECT * FROM book WHERE title LIKE CONCAT('%', #{title}, '%')
SELECT *
FROM book
WHERE title LIKE CONCAT('%', #{title}, '%')
</select>
<select id="findByAuthor" resultType="com.grtsinry43.bookmanagement.entity.Book">
SELECT b.* FROM book b
JOIN book_author ba ON b.book_id = ba.book_id
JOIN author a ON ba.author_id = a.author_id
SELECT b.*
FROM book b
JOIN book_author ba ON b.book_id = ba.book_id
JOIN author a ON ba.author_id = a.author_id
WHERE a.name LIKE CONCAT('%', #{authorName}, '%')
</select>
<select id="findByPublisher" resultType="com.grtsinry43.bookmanagement.entity.Book">
SELECT b.* FROM book b
JOIN publisher p ON b.publisher_id = p.publisher_id
SELECT b.*
FROM book b
JOIN publisher p ON b.publisher_id = p.publisher_id
WHERE p.name LIKE CONCAT('%', #{publisherName}, '%')
</select>
<insert id="insert" parameterType="com.grtsinry43.bookmanagement.entity.Book" useGeneratedKeys="true" keyProperty="bookId">
INSERT INTO book (title, isbn, price, stock, publish_date, publisher_id)
VALUES (#{title}, #{isbn}, #{price}, #{stock}, #{publishDate}, #{publisherId})
<!-- 1. 查询所有库存为0的图书单表+ORDER BY -->
<select id="findOutOfStockBooks" resultType="com.grtsinry43.bookmanagement.entity.Book">
SELECT * FROM book WHERE stock = 0 ORDER BY publish_date DESC
</select>
<!-- 2. 查询每个出版社的图书数量(连接+GROUP BY+聚合) -->
<select id="countBooksByPublisher" resultType="map">
SELECT p.name AS publisher_name, COUNT(b.book_id) AS book_count
FROM book b
JOIN publisher p ON b.publisher_id = p.publisher_id
GROUP BY p.name
ORDER BY book_count DESC
</select>
<!-- 3. 查询价格高于平均价格的图书(嵌套查询+单表) -->
<select id="findBooksAboveAveragePrice" resultType="com.grtsinry43.bookmanagement.entity.Book">
SELECT * FROM book WHERE price > (SELECT AVG(price) FROM book)
</select>
<!-- 4. 查询指定一组ISBN的图书IN集合查询 -->
<select id="findByIsbns" resultType="com.grtsinry43.bookmanagement.entity.Book">
SELECT * FROM book WHERE isbn IN
<foreach collection="isbns" item="isbn" open="(" separator="," close=")">
#{isbn}
</foreach>
</select>
<!-- 5. 查询有多位作者的图书(连接+GROUP BY+HAVING -->
<select id="findBooksWithMultipleAuthors" resultType="com.grtsinry43.bookmanagement.entity.Book">
SELECT b.*
FROM book b
JOIN book_author ba ON b.book_id = ba.book_id
GROUP BY b.book_id
HAVING COUNT(ba.author_id) > 1
</select>
<!-- 6. 查询每个作者的图书总价(连接+GROUP BY+SUM -->
<select id="sumBookPriceByAuthor" resultType="map">
SELECT a.name AS author_name, SUM(b.price) AS total_price
FROM book b
JOIN book_author ba ON b.book_id = ba.book_id
JOIN author a ON ba.author_id = a.author_id
GROUP BY a.name
</select>
<!-- 7. 查询未被任何订单购买过的图书嵌套NOT EXISTS -->
<select id="findBooksNeverOrdered" resultType="com.grtsinry43.bookmanagement.entity.Book">
SELECT * FROM book b WHERE NOT EXISTS (
SELECT 1 FROM order_item oi WHERE oi.book_id = b.book_id
)
</select>
<!-- 8. 查询最近出版的5本图书单表+ORDER BY+LIMIT -->
<select id="findLatestBooks" resultType="com.grtsinry43.bookmanagement.entity.Book">
SELECT * FROM book ORDER BY publish_date DESC LIMIT 5
</select>
<!-- 9. 查询价格在指定区间的图书BETWEEN集合查询 -->
<select id="findBooksByPriceRange" resultType="com.grtsinry43.bookmanagement.entity.Book">
SELECT * FROM book WHERE price BETWEEN #{minPrice} AND #{maxPrice}
</select>
<!-- 10. 查询每本书的销量(连接+GROUP BY+SUM -->
<select id="findBookSales" resultType="map">
SELECT b.book_id, b.title, SUM(oi.quantity) AS total_sales
FROM book b
JOIN order_item oi ON b.book_id = oi.book_id
GROUP BY b.book_id, b.title
ORDER BY total_sales DESC
</select>
<insert id="insert" parameterType="com.grtsinry43.bookmanagement.entity.Book" useGeneratedKeys="true"
keyProperty="bookId">
INSERT INTO book (title, isbn, price, stock, publish_date, publisher_id, author)
VALUES (#{title}, #{isbn}, #{price}, #{stock}, #{publishDate}, #{publisherId}, #{author})
</insert>
<update id="update" parameterType="com.grtsinry43.bookmanagement.entity.Book">
UPDATE book
SET title = #{title},
isbn = #{isbn},
price = #{price},
stock = #{stock},
SET title = #{title},
isbn = #{isbn},
price = #{price},
stock = #{stock},
publish_date = #{publishDate},
publisher_id = #{publisherId}
WHERE book_id = #{bookId}
</update>
<delete id="delete">
DELETE FROM book WHERE book_id = #{bookId}
DELETE
FROM book
WHERE book_id = #{bookId}
</delete>
</mapper>

View File

@ -11,6 +11,38 @@
VALUES (#{orderId}, #{bookId}, #{quantity}, #{unitPrice})
</insert>
<!-- 1. 查询某本书的所有订单明细(单表+ORDER BY -->
<select id="findByBookId" resultType="com.grtsinry43.bookmanagement.entity.OrderItem">
SELECT * FROM order_item WHERE book_id = #{bookId} ORDER BY order_id DESC
</select>
<!-- 2. 查询订单明细中数量大于指定值的记录(单表+条件) -->
<select id="findByQuantityGreaterThan" resultType="com.grtsinry43.bookmanagement.entity.OrderItem">
SELECT * FROM order_item WHERE quantity > #{quantity}
</select>
<!-- 3. 查询每本书的总售出数量(连接+GROUP BY+SUM -->
<select id="sumQuantityByBook" resultType="map">
SELECT b.title, SUM(oi.quantity) AS total_quantity
FROM order_item oi
JOIN book b ON oi.book_id = b.book_id
GROUP BY b.title
ORDER BY total_quantity DESC
</select>
<!-- 4. 查询某订单下所有图书的单价(连接查询) -->
<select id="findBookUnitPricesByOrderId" resultType="map">
SELECT b.title, oi.unit_price
FROM order_item oi
JOIN book b ON oi.book_id = b.book_id
WHERE oi.order_id = #{orderId}
</select>
<!-- 5. 查询未被任何订单明细引用的图书ID嵌套NOT IN -->
<select id="findBookIdsNotInOrderItems" resultType="int">
SELECT book_id FROM book WHERE book_id NOT IN (SELECT book_id FROM order_item)
</select>
<!-- Example for batch insert -->
<!--
<insert id="insertBatch" parameterType="java.util.List">

View File

@ -23,4 +23,72 @@
UPDATE orders SET status = #{status} WHERE order_id = #{orderId}
</update>
<!-- 1. 查询所有已完成订单(单表+ORDER BY -->
<select id="findCompletedOrders" resultType="com.grtsinry43.bookmanagement.entity.Orders">
SELECT * FROM orders WHERE status = 'COMPLETED' ORDER BY order_date DESC
</select>
<!-- 2. 查询每个用户的订单总金额(连接+GROUP BY+SUM -->
<select id="sumOrderAmountByReader" resultType="map">
SELECT r.reader_id, r.username, SUM(o.total_amount) AS total_amount
FROM orders o
JOIN reader r ON o.reader_id = r.reader_id
GROUP BY r.reader_id, r.username
ORDER BY total_amount DESC
</select>
<!-- 3. 查询金额大于平均值的订单(嵌套查询) -->
<select id="findOrdersAboveAverageAmount" resultType="com.grtsinry43.bookmanagement.entity.Orders">
SELECT * FROM orders WHERE total_amount > (SELECT AVG(total_amount) FROM orders)
</select>
<!-- 4. 查询指定状态集合的订单IN集合查询 -->
<select id="findByStatuses" resultType="com.grtsinry43.bookmanagement.entity.Orders">
SELECT * FROM orders WHERE status IN
<foreach collection="statuses" item="status" open="(" separator="," close=")">
#{status}
</foreach>
</select>
<!-- 5. 查询没有订单明细的订单嵌套NOT EXISTS -->
<select id="findOrdersWithoutItems" resultType="com.grtsinry43.bookmanagement.entity.Orders">
SELECT * FROM orders o WHERE NOT EXISTS (
SELECT 1 FROM order_item oi WHERE oi.order_id = o.order_id
)
</select>
<!-- 6. 查询每月订单数量(聚合+GROUP BY -->
<select id="countOrdersByMonth" resultType="map">
SELECT TO_CHAR(order_date, 'YYYY-MM') AS month, COUNT(*) AS order_count
FROM orders
GROUP BY TO_CHAR(order_date, 'YYYY-MM')
ORDER BY month DESC
</select>
<!-- 7. 查询最近一周的订单(单表+时间区间) -->
<select id="findOrdersInLastWeek" resultType="com.grtsinry43.bookmanagement.entity.Orders">
SELECT * FROM orders WHERE order_date >= NOW() - INTERVAL '7 days' ORDER BY order_date DESC
</select>
<!-- 8. 查询订单金额在指定区间的订单BETWEEN集合查询 -->
<select id="findOrdersByAmountRange" resultType="com.grtsinry43.bookmanagement.entity.Orders">
SELECT * FROM orders WHERE total_amount BETWEEN #{minAmount} AND #{maxAmount}
</select>
<!-- 9. 查询每个状态的订单数量(聚合+GROUP BY -->
<select id="countOrdersByStatus" resultType="map">
SELECT status, COUNT(*) AS order_count
FROM orders
GROUP BY status
</select>
<!-- 10. 查询有订单但未支付的用户(连接+嵌套EXISTS -->
<select id="findReadersWithUnpaidOrders" resultType="com.grtsinry43.bookmanagement.entity.Reader">
SELECT DISTINCT r.*
FROM reader r
WHERE EXISTS (
SELECT 1 FROM orders o WHERE o.reader_id = r.reader_id AND o.status = 'UNPAID'
)
</select>
</mapper>

View File

@ -30,4 +30,42 @@
DELETE FROM publisher WHERE publisher_id = #{publisherId}
</delete>
<!-- 1. 查询所有含有指定地址的出版社(单表+LIKE+ORDER BY -->
<select id="findByAddressLike" resultType="com.grtsinry43.bookmanagement.entity.Publisher">
SELECT * FROM publisher WHERE address LIKE CONCAT('%', #{address}, '%') ORDER BY name
</select>
<!-- 2. 查询出版图书数量大于5的出版社连接+GROUP BY+HAVING -->
<select id="findPublishersWithManyBooks" resultType="com.grtsinry43.bookmanagement.entity.Publisher">
SELECT p.*
FROM publisher p
JOIN book b ON p.publisher_id = b.publisher_id
GROUP BY p.publisher_id
HAVING COUNT(b.book_id) > 5
</select>
<!-- 3. 查询没有出版任何图书的出版社嵌套NOT EXISTS -->
<select id="findPublishersWithoutBooks" resultType="com.grtsinry43.bookmanagement.entity.Publisher">
SELECT * FROM publisher p WHERE NOT EXISTS (
SELECT 1 FROM book b WHERE b.publisher_id = p.publisher_id
)
</select>
<!-- 4. 查询指定一组ID的出版社IN集合查询 -->
<select id="findByIds" resultType="com.grtsinry43.bookmanagement.entity.Publisher">
SELECT * FROM publisher WHERE publisher_id IN
<foreach collection="ids" item="id" open="(" separator="," close=")">
#{id}
</foreach>
</select>
<!-- 5. 查询每个出版社的图书平均价格(连接+GROUP BY+AVG -->
<select id="avgBookPriceByPublisher" resultType="map">
SELECT p.name AS publisher_name, AVG(b.price) AS avg_price
FROM publisher p
JOIN book b ON p.publisher_id = b.publisher_id
GROUP BY p.name
ORDER BY avg_price DESC
</select>
</mapper>

View File

@ -27,4 +27,63 @@
UPDATE reader SET is_banned = #{isBanned} WHERE reader_id = #{readerId}
</update>
<!-- 2. 查询每个用户的订单数量(连接+GROUP BY+聚合) -->
<select id="findReaderOrderCount" resultType="map">
SELECT r.reader_id, r.username, COUNT(o.order_id) AS order_count
FROM reader r
LEFT JOIN orders o ON r.reader_id = o.reader_id
GROUP BY r.reader_id, r.username
ORDER BY order_count DESC
</select>
<!-- 3. 查询有订单的用户信息(连接查询) -->
<select id="findReadersWithOrders" resultType="com.grtsinry43.bookmanagement.entity.Reader">
SELECT DISTINCT r.*
FROM reader r
JOIN orders o ON r.reader_id = o.reader_id
</select>
<!-- 4. 查询没有下过订单的用户嵌套NOT IN -->
<select id="findReadersWithoutOrders" resultType="com.grtsinry43.bookmanagement.entity.Reader">
SELECT * FROM reader WHERE reader_id NOT IN (SELECT reader_id FROM orders)
</select>
<!-- 5. 查询用户名在指定集合内的用户IN集合查询 -->
<select id="findByUsernames" resultType="com.grtsinry43.bookmanagement.entity.Reader">
SELECT * FROM reader WHERE username IN
<foreach collection="usernames" item="name" open="(" separator="," close=")">
#{name}
</foreach>
</select>
<!-- 6. 查询被封禁用户数量(聚合) -->
<select id="countBannedReaders" resultType="int">
SELECT COUNT(*) FROM reader WHERE is_banned = TRUE
</select>
<!-- 7. 查询有订单且订单金额大于100的用户嵌套EXISTS+连接) -->
<select id="findReadersWithBigOrders" resultType="com.grtsinry43.bookmanagement.entity.Reader">
SELECT * FROM reader r WHERE EXISTS (
SELECT 1 FROM orders o WHERE o.reader_id = r.reader_id AND o.total_amount > 100
)
</select>
<!-- 8. 查询每个用户的最后一次下单时间(连接+GROUP BY+聚合) -->
<select id="findLastOrderDateByReader" resultType="map">
SELECT r.reader_id, r.username, MAX(o.order_date) AS last_order_date
FROM reader r
LEFT JOIN orders o ON r.reader_id = o.reader_id
GROUP BY r.reader_id, r.username
</select>
<!-- 9. 查询邮箱为某域名的用户单表LIKE -->
<select id="findByEmailDomain" resultType="com.grtsinry43.bookmanagement.entity.Reader">
SELECT * FROM reader WHERE email LIKE CONCAT('%', #{domain})
</select>
<!-- 10. 查询所有未被封禁的管理员(单表多条件) -->
<select id="findActiveAdmins" resultType="com.grtsinry43.bookmanagement.entity.Reader">
SELECT * FROM reader WHERE is_admin = TRUE AND is_banned = FALSE
</select>
</mapper>

View File

@ -1,5 +1,37 @@
-- 适用于 PostgreSQL 数据库
-- 触发器:当 book 库存变为 0 时,记录到 out_of_stock_log
CREATE TABLE IF NOT EXISTS out_of_stock_log (
log_id SERIAL PRIMARY KEY,
book_id INT NOT NULL,
out_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
CREATE OR REPLACE FUNCTION log_out_of_stock()
RETURNS TRIGGER AS $$
BEGIN
IF NEW.stock = 0 AND OLD.stock > 0 THEN
INSERT INTO out_of_stock_log (book_id) VALUES (NEW.book_id);
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS trg_book_out_of_stock ON book;
CREATE TRIGGER trg_book_out_of_stock
AFTER UPDATE ON book
FOR EACH ROW
EXECUTE FUNCTION log_out_of_stock();
-- 存储过程:批量封禁用户
CREATE OR REPLACE PROCEDURE ban_readers(usernames TEXT[])
LANGUAGE plpgsql
AS $$
BEGIN
UPDATE reader SET is_banned = TRUE WHERE username = ANY(usernames);
END;
$$;
-- 创建数据库(如需)
-- CREATE DATABASE book_management;
@ -52,7 +84,7 @@ CREATE TABLE reader
reader_id SERIAL PRIMARY KEY,
username VARCHAR(50) NOT NULL UNIQUE,
password VARCHAR(100) NOT NULL,
email VARCHAR(100) NOT NULL UNIQUE,
email VARCHAR(100) UNIQUE,
is_admin BOOLEAN NOT NULL DEFAULT FALSE,
is_banned BOOLEAN NOT NULL DEFAULT FALSE,
phone VARCHAR(20)
@ -76,4 +108,4 @@ CREATE TABLE order_item
book_id INT NOT NULL REFERENCES book (book_id),
quantity INT NOT NULL CHECK (quantity > 0),
unit_price NUMERIC(10, 2) NOT NULL CHECK (unit_price >= 0)
);
);