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