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

loc-mds-index-books.sql 4.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
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
  1. --- #dep loc-mds-books
  2. --- #step Index MARC fields
  3. CREATE INDEX IF NOT EXISTS book_marc_field_rec_idx ON locmds.book_marc_field (rec_id);
  4. --- #step Pull out control numbers
  5. CREATE MATERIALIZED VIEW IF NOT EXISTS locmds.book_marc_cn
  6. AS SELECT rec_id, trim(contents) AS control
  7. FROM locmds.book_marc_field
  8. WHERE tag = '001';
  9. CREATE INDEX IF NOT EXISTS book_marc_cn_rec_idx ON locmds.book_marc_cn (rec_id);
  10. ANALYZE locmds.book_marc_cn;
  11. CREATE MATERIALIZED VIEW IF NOT EXISTS locmds.book_lccn
  12. AS SELECT DISTINCT rec_id, trim(contents) AS lccn
  13. FROM locmds.book_marc_field
  14. WHERE tag = '010' AND sf_code = 'a';
  15. CREATE INDEX IF NOT EXISTS book_lccn_rec_idx ON locmds.book_lccn (rec_id);
  16. ANALYZE locmds.book_lccn;
  17. DROP VIEW IF EXISTS locmds.book_leader;
  18. CREATE VIEW locmds.book_leader
  19. AS SELECT rec_id, contents AS leader
  20. FROM locmds.book_marc_field
  21. WHERE tag = 'LDR';
  22. DROP VIEW IF EXISTS locmds.book_007_cat;
  23. CREATE VIEW locmds.book_007_cat
  24. AS SELECT rec_id, LEFT(contents, 1) AS cat_type
  25. FROM locmds.book_marc_field
  26. WHERE tag = '007';
  27. DROP VIEW IF EXISTS locmds.book_006_form;
  28. CREATE VIEW locmds.book_006_form
  29. AS SELECT rec_id, LEFT(contents, 1) AS form
  30. FROM locmds.book_marc_field
  31. WHERE tag = '006';
  32. DROP VIEW IF EXISTS locmds.book_record_code CASCADE;
  33. CREATE VIEW locmds.book_record_code
  34. AS SELECT rec_id,
  35. SUBSTR(contents, 6, 1) AS status,
  36. SUBSTR(contents, 7, 1) AS rec_type,
  37. substr(CONTENTS, 8, 1) AS bib_level
  38. FROM locmds.book_marc_field WHERE tag = 'LDR';
  39. DROP VIEW IF EXISTS locmds.book_gov_type;
  40. CREATE VIEW locmds.book_gov_type
  41. AS SELECT rec_id, SUBSTR(pd.contents, 29, 1) AS gd_type
  42. FROM locmds.book_record_code
  43. LEFT JOIN (SELECT rec_id, contents FROM locmds.book_marc_field WHERE tag = '008') pd USING (rec_id)
  44. WHERE rec_type IN ('a', 't');
  45. CREATE MATERIALIZED VIEW IF NOT EXISTS locmds.book_record_info
  46. AS SELECT rec_id, control AS marc_cn, lccn, status, rec_type, bib_level
  47. FROM locmds.book_marc_cn
  48. LEFT JOIN locmds.book_lccn USING (rec_id)
  49. JOIN locmds.book_record_code lrc USING (rec_id);
  50. CREATE INDEX IF NOT EXISTS book_record_rec_idx ON locmds.book_record_info (rec_id);
  51. CREATE INDEX IF NOT EXISTS book_record_control_idx ON locmds.book_record_info (marc_cn);
  52. CREATE INDEX IF NOT EXISTS book_record_lccn_idx ON locmds.book_record_info (lccn);
  53. ANALYZE locmds.book_record_info;
  54. -- A book is any text (MARC type a or t) that is not coded as a government document
  55. CREATE MATERIALIZED VIEW IF NOT EXISTS locmds.book
  56. AS SELECT rec_id, marc_cn, lccn, status, rec_type, bib_level
  57. FROM locmds.book_record_info
  58. LEFT JOIN (SELECT rec_id, contents FROM locmds.book_marc_field WHERE tag = '008') pd USING (rec_id)
  59. WHERE rec_type IN ('a', 't')
  60. AND (pd.contents IS NULL OR SUBSTRING(pd.contents, 29, 1) IN ('|', ' '));
  61. CREATE INDEX IF NOT EXISTS book_rec_idx ON locmds.book (rec_id);
  62. CREATE INDEX IF NOT EXISTS book_control_idx ON locmds.book (marc_cn);
  63. CREATE INDEX IF NOT EXISTS book_lccn_idx ON locmds.book (lccn);
  64. ANALYZE locmds.book;
  65. --- #step Index ISBNs
  66. CREATE MATERIALIZED VIEW IF NOT EXISTS locmds.book_extracted_isbn AS
  67. SELECT rec_id, extract_isbn(contents) AS isbn
  68. FROM locmds.book_marc_field
  69. WHERE tag = '020' AND sf_code = 'a';
  70. INSERT INTO isbn_id (isbn)
  71. WITH isbns AS (SELECT DISTINCT isbn FROM locmds.book_extracted_isbn WHERE isbn IS NOT NULL AND char_length(isbn) IN (10,13))
  72. SELECT isbn FROM isbns
  73. WHERE isbn NOT IN (SELECT isbn FROM isbn_id);
  74. ANALYZE isbn_id;
  75. CREATE MATERIALIZED VIEW IF NOT EXISTS locmds.book_rec_isbn
  76. AS SELECT rec_id, isbn_id
  77. FROM locmds.book JOIN locmds.book_extracted_isbn USING (rec_id) JOIN isbn_id USING (isbn)
  78. WHERE isbn IS NOT NULl AND char_length(isbn) IN (10,13);
  79. CREATE INDEX IF NOT EXISTS book_rec_isbn_rec_idx ON locmds.book_rec_isbn (rec_id);
  80. CREATE INDEX IF NOT EXISTS book_rec_isbn_isbn_idx ON locmds.book_rec_isbn (isbn_id);
  81. ANALYZE locmds.book_rec_isbn;
  82. --- #step Extract authors
  83. CREATE MATERIALIZED VIEW IF NOT EXISTS locmds.book_author_name
  84. AS SELECT rec_id, regexp_replace(contents, '\W+$', '') AS name
  85. FROM locmds.book_marc_field
  86. WHERE tag = '100' AND sf_code = 'a';
  87. CREATE INDEX IF NOT EXISTS book_author_name_rec_idx ON locmds.book_author_name (rec_id);
  88. CREATE INDEX IF NOT EXISTS book_author_name_name_idx ON locmds.book_author_name (name);
  89. --= #step Extract publication years
  90. CREATE MATERIALIZED VIEW IF NOT EXISTS locmds.book_pub_year
  91. AS SELECT rec_id, substring(contents from '(\d\d\d\d)') AS pub_year
  92. FROM locmds.book_marc_field
  93. WHERE tag = '260' AND sf_code = 'c' AND substring(contents from '(\d\d\d\d)') IS NOT NULL;
  94. CREATE INDEX IF NOT EXISTS book_pub_year_rec_idx ON locmds.book_pub_year (rec_id);
  95. ANALYZE locmds.book_pub_year;
Tip!

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

Comments

Loading...