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

File ddlscript5.sql, 5.1 KB (added by 201205, 2 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 InventoryId INTEGER NOT NULL REFERENCES Library(InventoryId)
44 ON DELETE CASCADE,
45 BookId INTEGER NOT NULL REFERENCES Book(BookId)
46 ON DELETE CASCADE
47);
48
49CREATE TABLE Wishlist(
50 WishId SERIAL PRIMARY KEY,
51 UserId INTEGER NOT NULL REFERENCES AppUser(UserId)
52 ON DELETE CASCADE,
53 Priority VARCHAR(10) CHECK (Priority IN ('High', 'Low', 'Medium'))
54);
55
56CREATE TABLE WishlistBook(
57 WishId INTEGER NOT NULL REFERENCES Wishlist(WishId)
58 ON DELETE CASCADE,
59 BookId INTEGER NOT NULL REFERENCES Book(BookId)
60 ON DELETE CASCADE
61);
62
63CREATE TABLE BookRequest(
64 RequestId SERIAL PRIMARY KEY,
65 RequesterId INTEGER NOT NULL REFERENCES AppUser(UserId)
66 ON DELETE CASCADE,
67 OwnerId INTEGER NOT NULL REFERENCES AppUser(UserId)
68 ON DELETE CASCADE,
69 BookId INTEGER NOT NULL REFERENCES Book(BookId)
70 ON DELETE CASCADE,
71 InventoryId INTEGER NOT NULL REFERENCES Library(InventoryId)
72 ON DELETE CASCADE,
73 RequestStatus VARCHAR(20) NOT NULL CHECK (RequestStatus IN ('Approved', 'Pending', 'Declined')),
74 RequestDate DATE NOT NULL
75);
76
77CREATE TABLE Transaction(
78 TransactionId SERIAL PRIMARY KEY,
79 RequestId INTEGER NOT NULL REFERENCES BookRequest(RequestId),
80 BorrowerId INTEGER NOT NULL REFERENCES AppUser(UserId),
81 LenderId INTEGER NOT NULL REFERENCES AppUser(UserId),
82 InventoryId INTEGER NOT NULL REFERENCES Library(InventoryId),
83 BorrowDate DATE NOT NULL,
84 ReturnDate DATE NOT NULL CHECK (ReturnDate > BorrowDate),
85 BorrowDuration INT NOT NULL,
86 SwapTransactionId INTEGER REFERENCES Transaction(TransactionId)
87 ON DELETE SET NULL
88);
89
90
91CREATE TABLE TransactionBook(
92 TransactionId INTEGER NOT NULL REFERENCES Transaction(TransactionId)
93 ON DELETE CASCADE,
94 BookId INTEGER NOT NULL REFERENCES Book(BookId)
95 ON DELETE CASCADE
96);
97
98CREATE TABLE Review(
99 ReviewId SERIAL PRIMARY KEY,
100 TransactionId INTEGER NOT NULL REFERENCES Transaction(TransactionId),
101 ReceiverId INTEGER NOT NULL REFERENCES AppUser(UserId),
102 GiverId INTEGER NOT NULL REFERENCES AppUser(UserId),
103 Rating INTEGER NOT NULL CHECK (Rating BETWEEN 1 AND 5),
104 ReviewerComment VARCHAR (100),
105 Date DATE NOT NULL
106);
107
108CREATE TABLE Message(
109 MessageId SERIAL PRIMARY KEY,
110 SenderId INTEGER NOT NULL REFERENCES AppUser(UserId),
111 ReceiverId INTEGER NOT NULL REFERENCES AppUser(UserId),
112 Time TIME NOT NULL,
113 Date DATE NOT NULL,
114 MessageContent VARCHAR(1000) NOT NULL
115);
116
117CREATE TABLE FriendRequest(
118 FriendshipId SERIAL PRIMARY KEY,
119 SenderId INTEGER NOT NULL REFERENCES AppUser(UserId),
120 ReceiverId INTEGER NOT NULL REFERENCES AppUser(UserId),
121 CHECK (SenderId != ReceiverId),
122 DateCreated DATE NOT NULL,
123 Status VARCHAR(20) NOT NULL CHECK (Status IN ('Accepted', 'Pending', 'Declined', 'Blocked'))
124);
125
126CREATE TABLE Report(
127 ReportId SERIAL PRIMARY KEY,
128 ReportedUserId INTEGER NOT NULL REFERENCES AppUser(UserId),
129 ReportingUserId INTEGER NOT NULL REFERENCES AppUser(UserId),
130 CHECK (ReportedUserId != ReportingUserId),
131 ReportType VARCHAR(20) NOT NULL CHECK (ReportType IN ('Harassment', 'Bullying', 'Hate speech', 'Spamming')),
132 ReportDate DATE NOT NULL,
133 Details VARCHAR (1000),
134 ReportStatus VARCHAR(20) NOT NULL CHECK (ReportStatus IN ('Pending', 'Accepted', 'Rejected', 'Resolved')),
135 ReportedEntity VARCHAR(20) NOT NULL CHECK (ReportedEntity IN ('Message', 'Rating', 'Profile', 'Library'))
136);
137
138
139CREATE TABLE Notification(
140 NotificationId SERIAL PRIMARY KEY,
141 TransactionId INTEGER REFERENCES Transaction(TransactionId)
142 ON DELETE CASCADE,
143 MessageId INTEGER REFERENCES Message(MessageId)
144 ON DELETE CASCADE,
145 FriendRequestId INTEGER REFERENCES FriendRequest(FriendshipId)
146 ON DELETE CASCADE,
147 BookRequestId INTEGER REFERENCES BookRequest(RequestId)
148 ON DELETE CASCADE,
149 Type VARCHAR(20) NOT NULL CHECK (Type IN ('System Update', 'Transaction', 'Reminder', 'Message', 'Friend Request', 'Book Request')),
150 Time TIME NOT NULL,
151 Date DATE NOT NULL,
152 Description VARCHAR (100) NOT NULL,
153 Status VARCHAR(20) NOT NULL CHECK (Status IN ('Read', 'Unread', 'Dismissed'))
154);
155
156CREATE TABLE UserNotification(
157 UserId INTEGER NOT NULL REFERENCES AppUser(UserId),
158 NotificationId INTEGER NOT NULL REFERENCES Notification(NotificationId)
159);