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.1 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
  1. --- #step Index book clusters
  2. CREATE MATERIALIZED VIEW IF NOT EXISTS gr.book_cluster
  3. AS SELECT DISTINCT gr_book_id, cluster
  4. FROM gr.book_isbn JOIN isbn_cluster USING (isbn_id);
  5. CREATE UNIQUE INDEX IF NOT EXISTS book_cluster_book_idx ON gr.book_cluster (gr_book_id);
  6. CREATE INDEX IF NOT EXISTS book_cluster_cluster_idx ON gr.book_cluster (cluster);
  7. ANALYZE gr.book_cluster;
  8. --- #step Extract user info
  9. CREATE TABLE IF NOT EXISTS gr.user_info (
  10. gr_user_rid SERIAL PRIMARY KEY,
  11. gr_user_id VARCHAR NOT NULL
  12. );
  13. CREATE TEMPORARY TABLE gr_new_users
  14. AS SELECT gr_interaction_data->>'user_id' AS gr_user_id
  15. FROM gr.raw_interaction LEFT JOIN gr.user_info ON (gr_user_id = gr_interaction_data->>'user_id')
  16. WHERE gr_user_rid IS NULL;
  17. INSERT INTO gr.user_info (gr_user_id)
  18. SELECT DISTINCT gr_user_id FROM gr_new_users;
  19. CREATE UNIQUE INDEX IF NOT EXISTS user_id_idx ON gr.user_info (gr_user_id);
  20. ANALYZE gr.user_info;
  21. --- #step Extract interaction data
  22. CREATE TABLE IF NOT EXISTS gr.interaction
  23. AS SELECT gr_interaction_rid, book_id, gr_user_rid, rating, (gr_interaction_data->'isRead')::boolean AS is_read, date_added, date_updated
  24. FROM gr.raw_interaction,
  25. jsonb_to_record(gr_interaction_data) AS
  26. x(book_id INTEGER, user_id VARCHAR, rating INTEGER,
  27. date_added TIMESTAMP WITH TIME ZONE, date_updated TIMESTAMP WITH TIME ZONE),
  28. gr.user_info
  29. WHERE user_id = gr_user_id;
  30. --- #step Index interaction data
  31. --- #allow invalid_table_definition
  32. -- if this step is already done, first ALTER TABLE will fail
  33. ALTER TABLE gr.interaction ADD CONSTRAINT gr_interaction_pk PRIMARY KEY (gr_interaction_rid);
  34. CREATE INDEX IF NOT EXISTS interaction_book_idx ON gr.interaction (book_id);
  35. CREATE INDEX IF NOT EXISTS interaction_user_idx ON gr.interaction (gr_user_rid);
  36. ALTER TABLE gr.interaction ADD CONSTRAINT gr_interaction_book_fk FOREIGN KEY (book_id) REFERENCES gr_book_ids (gr_book_id);
  37. ALTER TABLE gr.interaction ADD CONSTRAINT gr_interaction_user_fk FOREIGN KEY (gr_user_rid) REFERENCES gr.user_info (gr_user_rid);
  38. ANALYZE gr.interaction;
  39. --- #step Extract ratings
  40. CREATE MATERIALIZED VIEW IF NOT EXISTS gr.rating
  41. AS SELECT gr_user_rid AS user_id, cluster AS book_id,
  42. MEDIAN(rating) AS med_rating,
  43. (array_agg(rating ORDER BY date_updated DESC))[1] AS last_rating,
  44. COUNT(rating) AS nratings
  45. FROM gr.interaction
  46. JOIN gr.book_cluster ON (gr_book_id = book_id)
  47. WHERE rating > 0
  48. GROUP BY gr_user_rid, cluster;
  49. CREATE INDEX IF NOT EXISTS rating_user_idx ON gr.rating (user_id);
  50. CREATE INDEX IF NOT EXISTS rating_item_idx ON gr.rating (book_id);
  51. ANALYZE gr.rating;
  52. --- #step Extract add actions
  53. CREATE MATERIALIZED VIEW IF NOT EXISTS gr.add_action
  54. AS SELECT gr_user_rid AS user_id, cluster AS book_id,
  55. COUNT(rating) AS nactions
  56. FROM gr.interaction
  57. JOIN gr.book_cluster ON (gr_book_id = book_id)
  58. GROUP BY gr_user_rid, cluster;
  59. CREATE INDEX IF NOT EXISTS add_action_user_idx ON gr.add_action (user_id);
  60. CREATE INDEX IF NOT EXISTS add_action_item_idx ON gr.add_action (book_id);
  61. ANALYZE gr.add_action;
Tip!

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

Comments

Loading...