|
2 | 2 | -- tables to mimic the tables available on data.stackexchange.com |
3 | 3 |
|
4 | 4 | -- The `LATERAL` keyword requires PostgresSQL 9.3 |
| 5 | + |
| 6 | +-- The tables here assume the existence of `Tags` table which is absent |
| 7 | +-- from the Sept 2011 database dumps. Hence, the following two tables |
| 8 | +-- will be absent from the database which holds those dumps. See the README. |
5 | 9 | DROP TABLE IF EXISTS PostTags; |
6 | 10 | CREATE TABLE PostTags ( |
7 | 11 | PostId int not NULL, |
@@ -29,6 +33,30 @@ CREATE INDEX posttags_tagId_idx ON PostTags USING btree (TagId) |
29 | 33 | WITH (FILLFACTOR = 100); |
30 | 34 |
|
31 | 35 |
|
| 36 | +-- UserTagQA TABLE |
| 37 | +DROP TABLE IF EXISTS UserTagQA; |
| 38 | +CREATE TABLE UserTagQA ( |
| 39 | + UserId int, |
| 40 | + TagId int, |
| 41 | + Questions int, |
| 42 | + Answers int, |
| 43 | + PRIMARY KEY (UserId, TagId) |
| 44 | +); |
| 45 | +INSERT INTO UserTagQA |
| 46 | + ( SELECT P.ownerUserId AS UserId, |
| 47 | + PT.tagId AS TagId, |
| 48 | + sum(CASE P.PostTypeId WHEN 1 THEN 1 ELSE 0 END) AS Questions, |
| 49 | + sum(CASE P.PostTypeId WHEN 2 THEN 1 ELSE 0 END) AS Answers |
| 50 | + FROM Posts P JOIN PostTags PT ON PT.PostId = P.Id |
| 51 | + WHERE P.OwnerUserId IS NOT NULL |
| 52 | + GROUP BY P.OwnerUserId, PT.TagId |
| 53 | + ); |
| 54 | +CREATE INDEX usertagqa_questions_idx ON UserTagQA USING btree (Questions) |
| 55 | + WITH (FILLFACTOR = 100); |
| 56 | +CREATE INDEX usertagqa_answers_idx ON UserTagQA USING btree (Answers) |
| 57 | + WITH (FILLFACTOR = 100); |
| 58 | + |
| 59 | + |
32 | 60 | -- Tables containing static values |
33 | 61 |
|
34 | 62 | -- CloseAsOffTopicReasonTypes TABLE |
@@ -242,27 +270,3 @@ CREATE VIEW Answers AS |
242 | 270 | WHERE PostTypeId = 2; |
243 | 271 |
|
244 | 272 |
|
245 | | --- UserTagQA TABLE |
246 | | -DROP TABLE IF EXISTS UserTagQA; |
247 | | -CREATE TABLE UserTagQA ( |
248 | | - UserId int, |
249 | | - TagId int, |
250 | | - Questions int, |
251 | | - Answers int, |
252 | | - PRIMARY KEY (UserId, TagId) |
253 | | -); |
254 | | -INSERT INTO UserTagQA |
255 | | - ( SELECT P.ownerUserId AS UserId, |
256 | | - PT.tagId AS TagId, |
257 | | - sum(CASE P.PostTypeId WHEN 1 THEN 1 ELSE 0 END) AS Questions, |
258 | | - sum(CASE P.PostTypeId WHEN 2 THEN 1 ELSE 0 END) AS Answers |
259 | | - FROM Posts P JOIN PostTags PT ON PT.PostId = P.Id |
260 | | - WHERE P.OwnerUserId IS NOT NULL |
261 | | - GROUP BY P.OwnerUserId, PT.TagId |
262 | | - ); |
263 | | -CREATE INDEX usertagqa_questions_idx ON UserTagQA USING btree (Questions) |
264 | | - WITH (FILLFACTOR = 100); |
265 | | -CREATE INDEX usertagqa_answers_idx ON UserTagQA USING btree (Answers) |
266 | | - WITH (FILLFACTOR = 100); |
267 | | - |
268 | | - |
|
0 commit comments