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 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
  1. --- #step Add book PK
  2. --- #allow invalid_table_definition
  3. ALTER TABLE gr.raw_book ADD CONSTRAINT gr_raw_book_pk PRIMARY KEY (gr_book_rid);
  4. --- #step Add work PK
  5. --- #allow invalid_table_definition
  6. ALTER TABLE gr.raw_work ADD CONSTRAINT gr_raw_work_pk PRIMARY KEY (gr_work_rid);
  7. --- #step Add author PK
  8. --- #allow invalid_table_definition
  9. ALTER TABLE gr.raw_author ADD CONSTRAINT gr_raw_author_pk PRIMARY KEY (gr_author_rid);
  10. --- #step Extract work identifiers
  11. CREATE TABLE IF NOT EXISTS gr.work_ids
  12. AS SELECT gr_work_rid, (gr_work_data->>'work_id')::int AS gr_work_id
  13. FROM gr.raw_work;
  14. --- #step Index work identifiers
  15. --- #allow duplicate_object
  16. CREATE UNIQUE INDEX IF NOT EXISTS work_id_idx ON gr.work_ids (gr_work_id);
  17. ALTER TABLE gr.work_ids ADD CONSTRAINT gr_work_id_pk PRIMARY KEY (gr_work_rid);
  18. ALTER TABLE gr.work_ids ADD CONSTRAINT gr_work_id_fk FOREIGN KEY (gr_work_rid) REFERENCES gr.raw_work (gr_work_rid);
  19. ANALYZE gr.work_ids;
  20. --- #step Extract book identifiers
  21. CREATE TABLE IF NOT EXISTS gr.book_ids
  22. AS SELECT gr_book_rid,
  23. NULLIF(work_id, '')::int AS gr_work_id,
  24. book_id AS gr_book_id,
  25. NULLIF(trim(both from asin), '') AS gr_asin,
  26. NULLIF(trim(both from isbn), '') AS gr_isbn,
  27. NULLIF(trim(both from isbn13), '') AS gr_isbn13
  28. FROM gr.raw_book,
  29. jsonb_to_record(gr_book_data) AS x(work_id VARCHAR, book_id INTEGER, asin VARCHAR, isbn VARCHAR, isbn13 VARCHAR);
  30. --- #step Index book identifiers
  31. --- #allow invalid_table_definition
  32. -- If we have completed this step, the PK add will fail with invalid table definition
  33. ALTER TABLE gr.book_ids ADD CONSTRAINT gr_book_id_pk PRIMARY KEY (gr_book_rid);
  34. CREATE UNIQUE INDEX book_id_idx ON gr.book_ids (gr_book_id);
  35. CREATE INDEX book_work_idx ON gr.book_ids (gr_work_id);
  36. CREATE INDEX book_asin_idx ON gr.book_ids (gr_asin);
  37. CREATE INDEX book_isbn_idx ON gr.book_ids (gr_isbn);
  38. CREATE INDEX book_isbn13_idx ON gr.book_ids (gr_isbn13);
  39. ALTER TABLE gr.book_ids ADD CONSTRAINT gr_book_id_fk FOREIGN KEY (gr_book_rid) REFERENCES gr.raw_book (gr_book_rid);
  40. ALTER TABLE gr.book_ids ADD CONSTRAINT gr_book_id_work_fk FOREIGN KEY (gr_work_id) REFERENCES gr.work_ids (gr_work_id);
  41. ANALYZE gr.book_ids;
  42. --- #step Update ISBN ID records with new ISBNs from GoodReads
  43. INSERT INTO isbn_id (isbn)
  44. SELECT DISTINCT gr_isbn FROM gr.book_ids
  45. WHERE gr_isbn IS NOT NULL AND gr_isbn NOT IN (SELECT isbn FROM isbn_id);
  46. INSERT INTO isbn_id (isbn)
  47. SELECT gr_isbn13 FROM gr.book_ids
  48. WHERE gr_isbn13 IS NOT NULL AND gr_isbn13 NOT IN (SELECT isbn FROM isbn_id);
  49. --- #step Map ISBNs to book IDs
  50. CREATE TABLE IF NOT EXISTS gr.book_isbn
  51. 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
  52. FROM gr.book_ids, isbn_id
  53. WHERE isbn = gr_isbn OR isbn = gr_isbn13;
  54. --- #step Index GoodReads ISBNs
  55. --- #allow duplicate_object
  56. -- this will fail promptly with duplicate object if the index already exists
  57. CREATE INDEX book_isbn_book_idx ON gr.book_isbn (gr_book_id);
  58. CREATE INDEX book_isbn_isbn_idx ON gr.book_isbn (isbn_id);
  59. CREATE INDEX book_isbn_code_idx ON gr.book_isbn (book_code);
  60. ALTER TABLE gr.book_isbn ADD CONSTRAINT gr_book_isbn_book_fk FOREIGN KEY (gr_book_id) REFERENCES gr.book_ids (gr_book_id);
  61. ALTER TABLE gr.book_isbn ADD CONSTRAINT gr_book_isbn_isbn_fk FOREIGN KEY (isbn_id) REFERENCES isbn_id (isbn_id);
  62. ANALYZE gr.book_isbn;
  63. --- #step Save stage deps
  64. INSERT INTO stage_dep (stage_name, dep_name, dep_key)
  65. SELECT 'gr-index-books', stage_name, stage_key
  66. FROM stage_status
  67. WHERE stage_name IN ('gr-books', 'gr-works', 'gr-authors');
Tip!

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

Comments

Loading...