Register
Login
Resources
Docs Blog Datasets Glossary Case Studies Tutorials & Webinars
Product
Data Engine LLMs Platform Enterprise
Pricing Explore
Connect to our Discord channel

gr-index-ratings.sql 3.5 KB

You have to be logged in to leave a comment. Sign In
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
  1. --- #dep gr-interactions
  2. --- #dep cluster
  3. --- #dep gr-book-info
  4. --- #table gr.user_info
  5. --- #table gr.interaction
  6. --- #table gr.rating
  7. --- #step Add interaction PK
  8. --- #allow invalid_table_definition
  9. ALTER TABLE gr.raw_interaction ADD CONSTRAINT gr_raw_interaction_pk PRIMARY KEY (gr_interaction_rid);
  10. --- #step Extract user info
  11. CREATE TABLE IF NOT EXISTS gr.user_info (
  12. gr_user_rid SERIAL PRIMARY KEY,
  13. gr_user_id VARCHAR NOT NULL
  14. );
  15. CREATE TEMPORARY TABLE gr_new_users
  16. AS SELECT gr_interaction_data->>'user_id' AS gr_user_id
  17. FROM gr.raw_interaction LEFT JOIN gr.user_info ON (gr_user_id = gr_interaction_data->>'user_id')
  18. WHERE gr_user_rid IS NULL;
  19. INSERT INTO gr.user_info (gr_user_id)
  20. SELECT DISTINCT gr_user_id FROM gr_new_users;
  21. CREATE UNIQUE INDEX IF NOT EXISTS user_id_idx ON gr.user_info (gr_user_id);
  22. ANALYZE gr.user_info;
  23. --- #step Extract interaction data
  24. CREATE TABLE IF NOT EXISTS gr.interaction
  25. AS SELECT gr_interaction_rid, book_id AS gr_book_id, gr_user_rid, rating, (gr_interaction_data->'isRead')::boolean AS is_read, date_added, date_updated
  26. FROM gr.raw_interaction,
  27. jsonb_to_record(gr_interaction_data) AS
  28. x(book_id INTEGER, user_id VARCHAR, rating INTEGER,
  29. date_added TIMESTAMP WITH TIME ZONE, date_updated TIMESTAMP WITH TIME ZONE),
  30. gr.user_info
  31. WHERE user_id = gr_user_id;
  32. DROP VIEW IF EXISTS gr.work_interaction;
  33. CREATE VIEW gr.work_interaction
  34. AS SELECT ix.*, bid.gr_work_id
  35. FROM gr.interaction ix
  36. LEFT JOIN gr.book_ids bid USING (gr_book_id);
  37. --- #step Index interaction data
  38. --- #allow invalid_table_definition
  39. -- if this step is already done, first ALTER TABLE will fail
  40. ALTER TABLE gr.interaction ADD CONSTRAINT gr_interaction_pk PRIMARY KEY (gr_interaction_rid);
  41. CREATE INDEX IF NOT EXISTS interaction_book_idx ON gr.interaction (gr_book_id);
  42. CREATE INDEX IF NOT EXISTS interaction_user_idx ON gr.interaction (gr_user_rid);
  43. ALTER TABLE gr.interaction ADD CONSTRAINT gr_interaction_book_fk FOREIGN KEY (gr_book_id) REFERENCES gr.book_ids (gr_book_id);
  44. ALTER TABLE gr.interaction ADD CONSTRAINT gr_interaction_user_fk FOREIGN KEY (gr_user_rid) REFERENCES gr.user_info (gr_user_rid);
  45. ANALYZE gr.interaction;
  46. --- #step Extract ratings
  47. CREATE MATERIALIZED VIEW IF NOT EXISTS gr.rating
  48. AS SELECT gr_user_rid AS user_id, cluster AS book_id,
  49. MEDIAN(rating) AS rating,
  50. (array_agg(rating ORDER BY date_updated DESC))[1] AS last_rating,
  51. MEDIAN(EXTRACT(EPOCH FROM date_updated)) AS timestamp,
  52. COUNT(rating) AS nratings
  53. FROM gr.interaction
  54. JOIN gr.book_cluster USING (gr_book_id)
  55. WHERE rating > 0
  56. GROUP BY gr_user_rid, cluster;
  57. CREATE INDEX IF NOT EXISTS rating_user_idx ON gr.rating (user_id);
  58. CREATE INDEX IF NOT EXISTS rating_item_idx ON gr.rating (book_id);
  59. ANALYZE gr.rating;
  60. --- #step Extract add actions
  61. CREATE MATERIALIZED VIEW IF NOT EXISTS gr.add_action
  62. AS SELECT gr_user_rid AS user_id, cluster AS book_id,
  63. MEDIAN(rating) AS med_rating,
  64. (array_agg(rating ORDER BY date_updated DESC))[1] AS last_rating,
  65. COUNT(date_updated) AS nactions,
  66. MIN(EXTRACT(EPOCH FROM date_updated)) AS first_time,
  67. MAX(EXTRACT(EPOCH FROM date_updated)) AS last_time
  68. FROM gr.interaction
  69. JOIN gr.book_cluster USING (gr_book_id)
  70. GROUP BY gr_user_rid, cluster;
  71. CREATE INDEX IF NOT EXISTS add_action_user_idx ON gr.add_action (user_id);
  72. CREATE INDEX IF NOT EXISTS add_action_item_idx ON gr.add_action (book_id);
  73. ANALYZE gr.add_action;
Tip!

Press p or to see the previous file or, n or to see the next file

Comments

Loading...