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

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