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

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

Comments

Loading...