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

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

Comments

Loading...