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

ol-index.sql 8.2 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
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
  1. --- #dep ol-authors
  2. --- #dep ol-editions
  3. --- #dep ol-works
  4. --- #table ol.work_authors
  5. --- #table ol.edition_work
  6. --- #step Index OL author table
  7. --- #allow invalid_table_definition
  8. CREATE INDEX IF NOT EXISTS author_key_idx ON ol.author (author_key);
  9. ALTER TABLE ol.author ADD PRIMARY KEY (author_id);
  10. --- #step Index OL work table
  11. --- #allow invalid_table_definition
  12. CREATE INDEX IF NOT EXISTS work_key_idx ON ol.work (work_key);
  13. ALTER TABLE ol.work ADD PRIMARY KEY (work_id);
  14. --- #step Index OL edition table
  15. --- #allow invalid_table_definition
  16. CREATE INDEX IF NOT EXISTS edition_key_idx ON ol.edition (edition_key);
  17. ALTER TABLE ol.edition ADD PRIMARY KEY (edition_id);
  18. --- #step Set up work-author join table
  19. CREATE TABLE IF NOT EXISTS ol.work_authors
  20. AS SELECT work_id, author_id
  21. FROM ol.author
  22. JOIN (SELECT work_id, jsonb_array_elements((work_data->'authors')) #>> '{author,key}' AS author_key FROM ol.work) w
  23. USING (author_key);
  24. --- #step Index work-author join table
  25. CREATE INDEX work_author_wk_idx ON ol.work_authors (work_id);
  26. CREATE INDEX work_author_au_idx ON ol.work_authors (author_id);
  27. --- #step Author work FK
  28. --- #allow duplicate_object
  29. ALTER TABLE ol.work_authors ADD CONSTRAINT work_author_wk_fk FOREIGN KEY (work_id) REFERENCES ol.work;
  30. --- #step Author-work author FK
  31. --- #allow duplicate_object
  32. ALTER TABLE ol.work_authors ADD CONSTRAINT work_author_au_fk FOREIGN KEY (author_id) REFERENCES ol.author;
  33. --- #step Set up work first author table
  34. CREATE TABLE IF NOT EXISTS ol.work_first_author
  35. AS SELECT work_id, author_id
  36. FROM ol.author
  37. JOIN (SELECT work_id, work_data #>> '{authors,0,author,key}' AS author_key FROM ol.work) w
  38. USING (author_key);
  39. --- #step Index work first author table
  40. CREATE INDEX IF NOT EXISTS work_first_author_wk_idx ON ol.work_first_author (work_id);
  41. CREATE INDEX IF NOT EXISTS work_first_author_au_idx ON ol.work_first_author (author_id);
  42. --- #step First author work FK
  43. --- #allow duplicate_object
  44. ALTER TABLE ol.work_first_author ADD CONSTRAINT work_first_author_wk_fk FOREIGN KEY (work_id) REFERENCES ol.work;
  45. --- #step First author author FK
  46. --- #allow duplicate_object
  47. ALTER TABLE ol.work_first_author ADD CONSTRAINT work_first_author_au_fk FOREIGN KEY (author_id) REFERENCES ol.author;
  48. --- #step Set up edition-author join table
  49. CREATE TABLE IF NOT EXISTS ol.edition_author
  50. AS SELECT edition_id, author_id
  51. FROM ol.author
  52. JOIN (SELECT edition_id, jsonb_array_elements((edition_data->'authors')) ->> 'key' AS author_key
  53. FROM ol.edition) e
  54. USING (author_key);
  55. --- #step index edition-author join table
  56. CREATE INDEX IF NOT EXISTS edition_author_ed_idx ON ol.edition_author (edition_id);
  57. CREATE INDEX IF NOT EXISTS edition_author_au_idx ON ol.edition_author (author_id);
  58. --- #allow duplicate_object
  59. ALTER TABLE ol.edition_author ADD CONSTRAINT edition_author_wk_fk FOREIGN KEY (edition_id) REFERENCES ol.edition;
  60. --- #allow duplicate_object
  61. ALTER TABLE ol.edition_author ADD CONSTRAINT edition_author_au_fk FOREIGN KEY (author_id) REFERENCES ol.author;
  62. --- #step Create edition first-author table
  63. CREATE TABLE ol.edition_first_author
  64. AS SELECT edition_id, author_id
  65. FROM ol.author
  66. JOIN (SELECT edition_id, edition_data #>> '{authors,0,key}' AS author_key
  67. FROM ol.edition) e
  68. USING (author_key);
  69. --- #step Index edition first-author table
  70. CREATE INDEX IF NOT EXISTS edition_first_author_ed_idx ON ol.edition_first_author (edition_id);
  71. CREATE INDEX IF NOT EXISTS edition_first_author_au_idx ON ol.edition_first_author (author_id);
  72. --- #step Edition first author edition FK
  73. --- #allow duplicate_object
  74. ALTER TABLE ol.edition_first_author ADD CONSTRAINT edition_first_author_wk_fk FOREIGN KEY (edition_id) REFERENCES ol.edition;
  75. --- #step Edition first author author FK
  76. --- #allow duplicate_object
  77. ALTER TABLE ol.edition_first_author ADD CONSTRAINT edition_first_author_au_fk FOREIGN KEY (author_id) REFERENCES ol.author;
  78. --- #step Set up edition-work join table
  79. CREATE TABLE IF NOT EXISTS ol.edition_work
  80. AS SELECT edition_id, work_id
  81. FROM ol.work
  82. JOIN (SELECT edition_id, jsonb_array_elements((edition_data->'works')) ->> 'key' AS work_key FROM ol.edition) w
  83. USING (work_key);
  84. --- #step Index edition-work join table
  85. CREATE INDEX IF NOT EXISTS edition_work_ed_idx ON ol.edition_work (edition_id);
  86. CREATE INDEX IF NOT EXISTS edition_work_au_idx ON ol.edition_work (work_id);
  87. --- #step Edition-work edition FK
  88. --- #allow duplicate_object
  89. ALTER TABLE ol.edition_work ADD CONSTRAINT edition_work_ed_fk FOREIGN KEY (edition_id) REFERENCES ol.edition;
  90. --- #step Edition-work work FK
  91. --- #allow duplicate_object
  92. ALTER TABLE ol.edition_work ADD CONSTRAINT edition_work_wk_fk FOREIGN KEY (work_id) REFERENCES ol.work;
  93. --- #step Integrate ISBN/ASIN identifiers
  94. DROP TABLE IF EXISTS ol.edition_isbn CASCADE;
  95. CREATE TABLE ol.edition_isbn (
  96. edition_id INTEGER NOT NULL,
  97. isbn VARCHAR NOT NULL
  98. );
  99. WITH
  100. ol_edition_isbn10
  101. AS (SELECT edition_id, jsonb_array_elements_text(edition_data->'isbn_10') AS isbn
  102. FROM ol.edition)
  103. INSERT INTO ol.edition_isbn
  104. SELECT edition_id, isbn
  105. FROM (SELECT edition_id, extract_isbn(isbn) AS isbn
  106. FROM ol_edition_isbn10) isbns
  107. WHERE isbn IS NOT NULL AND char_length(isbn) IN (10,13);
  108. WITH
  109. ol_edition_isbn13
  110. AS (SELECT edition_id, jsonb_array_elements_text(edition_data->'isbn_13') AS isbn
  111. FROM ol.edition)
  112. INSERT INTO ol.edition_isbn
  113. SELECT edition_id, isbn
  114. FROM (SELECT edition_id, extract_isbn(isbn) AS isbn
  115. FROM ol_edition_isbn13) isbns
  116. WHERE isbn IS NOT NULL AND char_length(isbn) IN (10,13);
  117. WITH
  118. ol_edition_asin AS
  119. (SELECT edition_id, jsonb_array_elements_text(edition_data#>'{identifiers,amazon}') AS asin
  120. FROM ol.edition)
  121. INSERT INTO ol.edition_isbn
  122. SELECT edition_id, regexp_replace(upper(asin), '[- ]', '')
  123. FROM ol_edition_asin
  124. WHERE regexp_replace(upper(asin), '[- ]', '') ~ '^[A-Z0-9]{10}$';
  125. CREATE INDEX edition_isbn_ed_idx ON ol.edition_isbn (edition_id);
  126. CREATE INDEX edition_isbn_idx ON ol.edition_isbn (isbn);
  127. ALTER TABLE ol.edition_isbn ADD CONSTRAINT edition_work_ed_fk FOREIGN KEY (edition_id) REFERENCES ol.edition;
  128. ANALYZE ol.edition_isbn;
  129. --- #step Add OL ISBNs to global table
  130. INSERT INTO isbn_id (isbn)
  131. SELECT DISTINCT isbn FROM ol.edition_isbn
  132. WHERE isbn NOT IN (SELECT DISTINCT isbn FROM isbn_id);
  133. ANALYZE isbn_id;
  134. --- #step Link OL ISBNs
  135. DROP TABLE IF EXISTS ol.isbn_link CASCADE;
  136. CREATE TABLE ol.isbn_link (
  137. isbn_id INTEGER NOT NULL,
  138. edition_id INTEGER NOT NULL,
  139. work_id INTEGER NULL,
  140. book_code INTEGER NOT NULL
  141. );
  142. INSERT INTO ol.isbn_link
  143. SELECT isbn_id, edition_id, work_id,
  144. COALESCE(bc_of_work(work_id), bc_of_edition(edition_id))
  145. FROM isbn_id JOIN ol.edition_isbn USING (isbn) LEFT JOIN ol.edition_work USING (edition_id);
  146. CREATE INDEX isbn_link_ed_idx ON ol.isbn_link (edition_id);
  147. CREATE INDEX isbn_link_wk_idx ON ol.isbn_link (work_id);
  148. CREATE INDEX isbn_link_bc_idx ON ol.isbn_link (book_code);
  149. CREATE INDEX isbn_link_isbn_idx ON ol.isbn_link (isbn_id);
  150. ALTER TABLE ol.isbn_link ADD CONSTRAINT ol_isbn_link_work_fk FOREIGN KEY (work_id) REFERENCES ol.work;
  151. ALTER TABLE ol.isbn_link ADD CONSTRAINT ol_isbn_link_ed_fk FOREIGN KEY (edition_id) REFERENCES ol.edition;
  152. ANALYZE ol.isbn_link;
  153. --- #step Tabulate author names
  154. DROP TABLE IF EXISTS ol.author_name CASCADE;
  155. CREATE TABLE ol.author_name (
  156. author_id INTEGER NOT NULL,
  157. author_name VARCHAR NOT NULL,
  158. name_source VARCHAR NOT NULL
  159. );
  160. INSERT INTO ol.author_name
  161. SELECT author_id, author_data ->> 'name', 'name'
  162. FROM ol.author WHERE author_data->>'name' IS NOT NULL;
  163. INSERT INTO ol.author_name
  164. SELECT author_id, author_data ->> 'personal_name', 'personal'
  165. FROM ol.author WHERE author_data ? 'personal_name';
  166. INSERT INTO ol.author_name
  167. SELECT author_id, jsonb_array_elements_text(author_data -> 'alternate_names'),
  168. 'alternate'
  169. FROM ol.author WHERE author_data ? 'alternate_names';
  170. CREATE INDEX author_name_idx ON ol.author_name (author_id);
  171. CREATE INDEX author_name_name_idx ON ol.author_name (author_name);
  172. ANALYZE ol.author_name;
  173. --- #step Catalog work subjects
  174. CREATE MATERIALIZED VIEW IF NOT EXISTS ol.work_subject
  175. AS SELECT work_id, jsonb_array_elements_text(work_data->'subjects') AS subject
  176. FROM ol.work;
  177. CREATE INDEX IF NOT EXISTS work_subject_work_idx ON ol.work_subject (work_id);
  178. CREATE INDEX IF NOT EXISTS work_subject_subj_idx ON ol.work_subject (subject);
Tip!

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

Comments

Loading...