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-books.sql 4.3 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
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
  1. --- #dep gr-books
  2. --- #dep gr-works
  3. --- #dep gr-authors
  4. --- #table gr.work_ids
  5. --- #table gr.book_ids
  6. --- #step Add book PK
  7. --- #allow invalid_table_definition
  8. ALTER TABLE gr.raw_book ADD CONSTRAINT gr_raw_book_pk PRIMARY KEY (gr_book_rid);
  9. --- #step Add work PK
  10. --- #allow invalid_table_definition
  11. ALTER TABLE gr.raw_work ADD CONSTRAINT gr_raw_work_pk PRIMARY KEY (gr_work_rid);
  12. --- #step Add author PK
  13. --- #allow invalid_table_definition
  14. ALTER TABLE gr.raw_author ADD CONSTRAINT gr_raw_author_pk PRIMARY KEY (gr_author_rid);
  15. --- #step Add book-genre PK
  16. --- #allow invalid_table_definition
  17. ALTER TABLE gr.raw_book_genres ADD CONSTRAINT gr_raw_book_genres_pk PRIMARY KEY (gr_book_genres_rid);
  18. --- #step Extract work identifiers
  19. CREATE TABLE IF NOT EXISTS gr.work_ids
  20. AS SELECT gr_work_rid, (gr_work_data->>'work_id')::int AS gr_work_id
  21. FROM gr.raw_work;
  22. --- #step Index work identifiers
  23. --- #allow duplicate_object
  24. --- #allow invalid_table_definition
  25. CREATE UNIQUE INDEX IF NOT EXISTS work_id_idx ON gr.work_ids (gr_work_id);
  26. ALTER TABLE gr.work_ids ADD CONSTRAINT gr_work_id_pk PRIMARY KEY (gr_work_rid);
  27. ALTER TABLE gr.work_ids ADD CONSTRAINT gr_work_id_fk FOREIGN KEY (gr_work_rid) REFERENCES gr.raw_work (gr_work_rid);
  28. ANALYZE gr.work_ids;
  29. --- #step Extract book identifiers
  30. CREATE TABLE IF NOT EXISTS gr.book_ids
  31. AS SELECT gr_book_rid,
  32. NULLIF(work_id, '')::int AS gr_work_id,
  33. book_id AS gr_book_id,
  34. NULLIF(trim(both from asin), '') AS gr_asin,
  35. NULLIF(trim(both from isbn), '') AS gr_isbn,
  36. NULLIF(trim(both from isbn13), '') AS gr_isbn13
  37. FROM gr.raw_book,
  38. jsonb_to_record(gr_book_data) AS x(work_id VARCHAR, book_id INTEGER, asin VARCHAR, isbn VARCHAR, isbn13 VARCHAR);
  39. --- #step Index book identifiers
  40. --- #allow invalid_table_definition
  41. -- If we have completed this step, the PK add will fail with invalid table definition
  42. ALTER TABLE gr.book_ids ADD CONSTRAINT gr_book_id_pk PRIMARY KEY (gr_book_rid);
  43. CREATE UNIQUE INDEX book_id_idx ON gr.book_ids (gr_book_id);
  44. CREATE INDEX book_work_idx ON gr.book_ids (gr_work_id);
  45. CREATE INDEX book_asin_idx ON gr.book_ids (gr_asin);
  46. CREATE INDEX book_isbn_idx ON gr.book_ids (gr_isbn);
  47. CREATE INDEX book_isbn13_idx ON gr.book_ids (gr_isbn13);
  48. ALTER TABLE gr.book_ids ADD CONSTRAINT gr_book_id_fk FOREIGN KEY (gr_book_rid) REFERENCES gr.raw_book (gr_book_rid);
  49. ALTER TABLE gr.book_ids ADD CONSTRAINT gr_book_id_work_fk FOREIGN KEY (gr_work_id) REFERENCES gr.work_ids (gr_work_id);
  50. ANALYZE gr.book_ids;
  51. --- #step Update ISBN ID records with new ISBNs from GoodReads
  52. INSERT INTO isbn_id (isbn)
  53. SELECT DISTINCT gr_isbn FROM gr.book_ids
  54. WHERE gr_isbn IS NOT NULL AND gr_isbn NOT IN (SELECT isbn FROM isbn_id);
  55. INSERT INTO isbn_id (isbn)
  56. SELECT DISTINCT gr_isbn13 FROM gr.book_ids
  57. WHERE gr_isbn13 IS NOT NULL AND gr_isbn13 NOT IN (SELECT isbn FROM isbn_id);
  58. --- #step Update ISBN ID records with ASINs from GoodReads
  59. INSERT INTO isbn_id (isbn)
  60. SELECT DISTINCT gr_asin FROM gr.book_ids
  61. WHERE gr_asin IS NOT NULL AND gr_asin NOT IN (SELECT isbn FROM isbn_id);
  62. --- #step Map ISBNs to book IDs
  63. CREATE TABLE IF NOT EXISTS gr.book_isbn
  64. AS SELECT gr_book_id, isbn_id, COALESCE(bc_of_gr_work(gr_work_id), bc_of_gr_book(gr_book_id)) AS book_code
  65. FROM gr.book_ids, isbn_id
  66. WHERE isbn = gr_isbn OR isbn = gr_isbn13;
  67. --- #step Index GoodReads ISBNs
  68. --- #allow duplicate_object
  69. --- #allow duplicate_table
  70. -- this will fail promptly with duplicate object if the index already exists
  71. CREATE INDEX book_isbn_book_idx ON gr.book_isbn (gr_book_id);
  72. CREATE INDEX book_isbn_isbn_idx ON gr.book_isbn (isbn_id);
  73. CREATE INDEX book_isbn_code_idx ON gr.book_isbn (book_code);
  74. ALTER TABLE gr.book_isbn ADD CONSTRAINT gr_book_isbn_book_fk FOREIGN KEY (gr_book_id) REFERENCES gr.book_ids (gr_book_id);
  75. ALTER TABLE gr.book_isbn ADD CONSTRAINT gr_book_isbn_isbn_fk FOREIGN KEY (isbn_id) REFERENCES isbn_id (isbn_id);
  76. ANALYZE gr.book_isbn;
  77. --- #step Index GoodReads book genres
  78. --- #allow duplicate_table
  79. CREATE TABLE IF NOT EXISTS gr.book_genres
  80. AS SELECT gr_book_rid, gr_book_id, key AS genre, value AS score
  81. FROM gr.raw_book_genres, jsonb_each_text(gr_book_genres_data->'genres'),
  82. gr.book_ids
  83. WHERE gr_book_id = (gr_book_genres_data->>'book_id')::int;
  84. CREATE INDEX bg_book_rid ON gr.book_genres (gr_book_rid);
  85. CREATE INDEX bg_book_id ON gr.book_genres (gr_book_id);
Tip!

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

Comments

Loading...