Логички и физички дизајн - Креирање база податоци (со SQL DDL): ddlscript6.sql

File ddlscript6.sql, 5.3 KB (added by 201205, 6 days ago)
Line 
1CREATE TABLE AppUser(
2 UserId SERIAL PRIMARY KEY,
3 FirstName VARCHAR(30) NOT NULL,
4 LastName VARCHAR(30) NOT NULL,
5 Email VARCHAR(100) UNIQUE NOT NULL,
6 Username VARCHAR(30) UNIQUE NOT NULL,
7 Password VARCHAR(50) NOT NULL,
8 City VARCHAR(30) NOT NULL,
9 Neighborhood VARCHAR(30) NOT NULL,
10 Bio VARCHAR(150),
11 Quote VARCHAR(250)
12);
13
14CREATE TABLE Book(
15 BookId SERIAL PRIMARY KEY,
16 Title VARCHAR(150) NOT NULL,
17 Author VARCHAR(100) NOT NULL,
18 Language VARCHAR(30) NOT NULL,
19 ImageURL VARCHAR(300)
20);
21
22CREATE TABLE BookISBN(
23 BookId INTEGER NOT NULL REFERENCES Book(BookId)
24 ON DELETE CASCADE,
25 ISBN VARCHAR(30) NOT NULL
26);
27
28CREATE TABLE Genre(
29 BookId INTEGER NOT NULL REFERENCES Book(BookId)
30 ON DELETE CASCADE,
31 Genre VARCHAR(50) NOT NULL
32);
33
34CREATE TABLE Library(
35 InventoryId SERIAL PRIMARY KEY,
36 UserId INTEGER NOT NULL REFERENCES AppUser(UserId)
37 ON DELETE CASCADE,
38 Availability VARCHAR(20) NOT NULL DEFAULT 'Available' CHECK (Availability IN ('Available', 'Not Available', 'Reserved')),
39 Condition VARCHAR(20) NOT NULL CHECK (Condition IN ('New', 'Like New', 'Good', 'Poor'))
40);
41
42CREATE TABLE LibraryBook(
43 LibraryBookId SERIAL PRIMARY KEY,
44 InventoryId INTEGER NOT NULL REFERENCES Library(InventoryId)
45 ON DELETE CASCADE,
46 BookId INTEGER NOT NULL REFERENCES Book(BookId)
47 ON DELETE CASCADE
48);
49
50CREATE TABLE Wishlist(
51 WishId SERIAL PRIMARY KEY,
52 UserId INTEGER NOT NULL REFERENCES AppUser(UserId)
53 ON DELETE CASCADE,
54 Priority VARCHAR(10) CHECK (Priority IN ('High', 'Low', 'Medium'))
55);
56
57CREATE TABLE WishlistBook(
58 WishlistBookId SERIAL PRIMARY KEY,
59 WishId INTEGER NOT NULL REFERENCES Wishlist(WishId)
60 ON DELETE CASCADE,
61 BookId INTEGER NOT NULL REFERENCES Book(BookId)
62 ON DELETE CASCADE
63);
64
65CREATE TABLE BookRequest(
66 RequestId SERIAL PRIMARY KEY,
67 RequesterId INTEGER NOT NULL REFERENCES AppUser(UserId)
68 ON DELETE CASCADE,
69 OwnerId INTEGER NOT NULL REFERENCES AppUser(UserId)
70 ON DELETE CASCADE,
71 BookId INTEGER NOT NULL REFERENCES Book(BookId)
72 ON DELETE CASCADE,
73 InventoryId INTEGER NOT NULL REFERENCES Library(InventoryId)
74 ON DELETE CASCADE,
75 RequestStatus VARCHAR(20) NOT NULL CHECK (RequestStatus IN ('Approved', 'Pending', 'Declined')),
76 RequestDate DATE NOT NULL
77);
78
79CREATE TABLE Transaction(
80 TransactionId SERIAL PRIMARY KEY,
81 RequestId INTEGER NOT NULL REFERENCES BookRequest(RequestId),
82 BorrowerId INTEGER NOT NULL REFERENCES AppUser(UserId),
83 LenderId INTEGER NOT NULL REFERENCES AppUser(UserId),
84 InventoryId INTEGER NOT NULL REFERENCES Library(InventoryId),
85 BorrowDate DATE NOT NULL,
86 ReturnDate DATE NOT NULL CHECK (ReturnDate > BorrowDate),
87 BorrowDuration INT NOT NULL,
88 SwapTransactionId INTEGER REFERENCES Transaction(TransactionId)
89 ON DELETE SET NULL
90);
91
92
93CREATE TABLE TransactionBook(
94 TransactionBookId SERIAL PRIMARY KEY,
95 TransactionId INTEGER NOT NULL REFERENCES Transaction(TransactionId)
96 ON DELETE CASCADE,
97 BookId INTEGER NOT NULL REFERENCES Book(BookId)
98 ON DELETE CASCADE
99);
100
101CREATE TABLE Review(
102 ReviewId SERIAL PRIMARY KEY,
103 TransactionId INTEGER NOT NULL REFERENCES Transaction(TransactionId),
104 ReceiverId INTEGER NOT NULL REFERENCES AppUser(UserId),
105 GiverId INTEGER NOT NULL REFERENCES AppUser(UserId),
106 Rating INTEGER NOT NULL CHECK (Rating BETWEEN 1 AND 5),
107 ReviewerComment VARCHAR (100),
108 Date DATE NOT NULL
109);
110
111CREATE TABLE Message(
112 MessageId SERIAL PRIMARY KEY,
113 SenderId INTEGER NOT NULL REFERENCES AppUser(UserId),
114 ReceiverId INTEGER NOT NULL REFERENCES AppUser(UserId),
115 Time TIME NOT NULL,
116 Date DATE NOT NULL,
117 MessageContent VARCHAR(1000) NOT NULL
118);
119
120CREATE TABLE FriendRequest(
121 FriendshipId SERIAL PRIMARY KEY,
122 SenderId INTEGER NOT NULL REFERENCES AppUser(UserId),
123 ReceiverId INTEGER NOT NULL REFERENCES AppUser(UserId),
124 CHECK (SenderId != ReceiverId),
125 DateCreated DATE NOT NULL,
126 Status VARCHAR(20) NOT NULL CHECK (Status IN ('Accepted', 'Pending', 'Declined', 'Blocked'))
127);
128
129CREATE TABLE Report(
130 ReportId SERIAL PRIMARY KEY,
131 ReportedUserId INTEGER NOT NULL REFERENCES AppUser(UserId),
132 ReportingUserId INTEGER NOT NULL REFERENCES AppUser(UserId),
133 CHECK (ReportedUserId != ReportingUserId),
134 ReportType VARCHAR(20) NOT NULL CHECK (ReportType IN ('Harassment', 'Bullying', 'Hate speech', 'Spamming')),
135 ReportDate DATE NOT NULL,
136 Details VARCHAR (1000),
137 ReportStatus VARCHAR(20) NOT NULL CHECK (ReportStatus IN ('Pending', 'Accepted', 'Rejected', 'Resolved')),
138 ReportedEntity VARCHAR(20) NOT NULL CHECK (ReportedEntity IN ('Message', 'Rating', 'Profile', 'Library'))
139);
140
141
142CREATE TABLE Notification(
143 NotificationId SERIAL PRIMARY KEY,
144 TransactionId INTEGER REFERENCES Transaction(TransactionId)
145 ON DELETE CASCADE,
146 MessageId INTEGER REFERENCES Message(MessageId)
147 ON DELETE CASCADE,
148 FriendRequestId INTEGER REFERENCES FriendRequest(FriendshipId)
149 ON DELETE CASCADE,
150 BookRequestId INTEGER REFERENCES BookRequest(RequestId)
151 ON DELETE CASCADE,
152 Type VARCHAR(20) NOT NULL CHECK (Type IN ('System Update', 'Transaction', 'Reminder', 'Message', 'Friend Request', 'Book Request')),
153 Time TIME NOT NULL,
154 Date DATE NOT NULL,
155 Description VARCHAR (100) NOT NULL,
156 Status VARCHAR(20) NOT NULL CHECK (Status IN ('Read', 'Unread', 'Dismissed'))
157);
158
159CREATE TABLE UserNotification(
160 UserNotificationId SERIAL PRIMARY KEY,
161 UserId INTEGER NOT NULL REFERENCES AppUser(UserId),
162 NotificationId INTEGER NOT NULL REFERENCES Notification(NotificationId)
163);