3 -- Host: localhost Database: koha30test
4 -- ------------------------------------------------------
5 -- Server version 4.1.22
7 /*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */;
8 /*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */;
9 /*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */;
10 /*!40103 SET @OLD_TIME_ZONE=@@TIME_ZONE */;
11 /*!40101 SET NAMES utf8 */;
12 /*!40103 SET TIME_ZONE='+00:00' */;
13 /*!40014 SET @OLD_UNIQUE_CHECKS=@@UNIQUE_CHECKS, UNIQUE_CHECKS=0 */;
14 /*!40014 SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0 */;
15 /*!40101 SET @OLD_SQL_MODE=@@SQL_MODE, SQL_MODE='NO_AUTO_VALUE_ON_ZERO' */;
16 /*!40111 SET @OLD_SQL_NOTES=@@SQL_NOTES, SQL_NOTES=0 */;
19 -- Table structure for table `auth_header`
22 DROP TABLE IF EXISTS `auth_header`;
23 CREATE TABLE `auth_header` (
24 `authid` bigint(20) unsigned NOT NULL auto_increment,
25 `authtypecode` varchar(10) NOT NULL default '',
26 `datecreated` date default NULL,
27 `modification_time` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
28 `origincode` varchar(20) default NULL,
29 `authtrees` mediumtext,
31 `linkid` bigint(20) default NULL,
32 `marcxml` longtext NOT NULL,
33 PRIMARY KEY (`authid`),
34 KEY `origincode` (`origincode`)
35 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
38 -- Table structure for table `auth_subfield_structure`
41 DROP TABLE IF EXISTS `auth_subfield_structure`;
42 CREATE TABLE `auth_subfield_structure` (
43 `authtypecode` varchar(10) NOT NULL default '',
44 `tagfield` varchar(3) NOT NULL default '',
45 `tagsubfield` varchar(1) NOT NULL default '',
46 `liblibrarian` varchar(255) NOT NULL default '',
47 `libopac` varchar(255) NOT NULL default '',
48 `repeatable` tinyint(4) NOT NULL default 0,
49 `mandatory` tinyint(4) NOT NULL default 0,
50 `tab` tinyint(1) default NULL,
51 `authorised_value` varchar(10) default NULL,
52 `value_builder` varchar(80) default NULL,
53 `seealso` varchar(255) default NULL,
54 `isurl` tinyint(1) default NULL,
55 `hidden` tinyint(3) NOT NULL default 0,
56 `linkid` tinyint(1) NOT NULL default 0,
57 `kohafield` varchar(45) NULL default '',
58 `frameworkcode` varchar(10) NOT NULL default '',
59 `defaultvalue` TEXT DEFAULT '',
60 PRIMARY KEY (`authtypecode`,`tagfield`,`tagsubfield`),
61 KEY `tab` (`authtypecode`,`tab`),
62 CONSTRAINT `auth_subfield_structure_ibfk_1` FOREIGN KEY (`authtypecode`) REFERENCES `auth_types` (`authtypecode`) ON DELETE CASCADE ON UPDATE CASCADE
63 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
66 -- Table structure for table `auth_tag_structure`
69 DROP TABLE IF EXISTS `auth_tag_structure`;
70 CREATE TABLE `auth_tag_structure` (
71 `authtypecode` varchar(10) NOT NULL default '',
72 `tagfield` varchar(3) NOT NULL default '',
73 `liblibrarian` varchar(255) NOT NULL default '',
74 `libopac` varchar(255) NOT NULL default '',
75 `repeatable` tinyint(4) NOT NULL default 0,
76 `mandatory` tinyint(4) NOT NULL default 0,
77 `authorised_value` varchar(10) default NULL,
78 PRIMARY KEY (`authtypecode`,`tagfield`),
79 CONSTRAINT `auth_tag_structure_ibfk_1` FOREIGN KEY (`authtypecode`) REFERENCES `auth_types` (`authtypecode`) ON DELETE CASCADE ON UPDATE CASCADE
80 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
83 -- Table structure for table `auth_types`
86 DROP TABLE IF EXISTS `auth_types`;
87 CREATE TABLE `auth_types` (
88 `authtypecode` varchar(10) NOT NULL default '',
89 `authtypetext` varchar(255) NOT NULL default '',
90 `auth_tag_to_report` varchar(3) NOT NULL default '',
91 `summary` mediumtext NOT NULL,
92 PRIMARY KEY (`authtypecode`)
93 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
96 -- Table structure for table `authorised_values`
99 DROP TABLE IF EXISTS `authorised_values`;
100 CREATE TABLE `authorised_values` ( -- stores values for authorized values categories and values
101 `id` int(11) NOT NULL auto_increment, -- unique key, used to identify the authorized value
102 `category` varchar(32) NOT NULL default '', -- key used to identify the authorized value category
103 `authorised_value` varchar(80) NOT NULL default '', -- code use to identify the authorized value
104 `lib` varchar(200) default NULL, -- authorized value description as printed in the staff client
105 `lib_opac` varchar(200) default NULL, -- authorized value description as printed in the OPAC
106 `imageurl` varchar(200) default NULL, -- authorized value URL
108 KEY `name` (`category`),
110 KEY `auth_value_idx` (`authorised_value`)
111 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
114 -- Table structure for table `biblio`
117 DROP TABLE IF EXISTS `biblio`;
118 CREATE TABLE `biblio` ( -- table that stores bibliographic information
119 `biblionumber` int(11) NOT NULL auto_increment, -- unique identifier assigned to each bibliographic record
120 `frameworkcode` varchar(4) NOT NULL default '', -- foriegn key from the biblio_framework table to identify which framework was used in cataloging this record
121 `author` mediumtext, -- statement of responsibility from MARC record (100$a in MARC21)
122 `title` mediumtext, -- title (without the subtitle) from the MARC record (245$a in MARC21)
123 `unititle` mediumtext, -- uniform title (without the subtitle) from the MARC record (240$a in MARC21)
124 `notes` mediumtext, -- values from the general notes field in the MARC record (500$a in MARC21) split by bar (|)
125 `serial` tinyint(1) default NULL, -- Boolean indicating whether biblio is for a serial
126 `seriestitle` mediumtext,
127 `copyrightdate` smallint(6) default NULL, -- publication or copyright date from the MARC record
128 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- date and time this record was last touched
129 `datecreated` DATE NOT NULL, -- the date this record was added to Koha
130 `abstract` mediumtext, -- summary from the MARC record (520$a in MARC21)
131 PRIMARY KEY (`biblionumber`),
132 KEY `blbnoidx` (`biblionumber`)
133 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
136 -- Table structure for table `biblio_framework`
139 DROP TABLE IF EXISTS `biblio_framework`;
140 CREATE TABLE `biblio_framework` ( -- information about MARC frameworks
141 `frameworkcode` varchar(4) NOT NULL default '', -- the unique code assigned to the framework
142 `frameworktext` varchar(255) NOT NULL default '', -- the description/name given to the framework
143 PRIMARY KEY (`frameworkcode`)
144 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
147 -- Table structure for table `biblioitems`
150 DROP TABLE IF EXISTS `biblioitems`;
151 CREATE TABLE `biblioitems` ( -- information related to bibliographic records in Koha
152 `biblioitemnumber` int(11) NOT NULL auto_increment, -- primary key, unique identifier assigned by Koha
153 `biblionumber` int(11) NOT NULL default 0, -- foreign key linking this table to the biblio table
156 `itemtype` varchar(10) default NULL, -- biblio level item type (MARC21 942$c)
157 `isbn` mediumtext, -- ISBN (MARC21 020$a)
158 `issn` mediumtext, -- ISSN (MARC21 022$a)
159 `ean` varchar(13) default NULL,
160 `publicationyear` text,
161 `publishercode` varchar(255) default NULL, -- publisher (MARC21 260$b)
162 `volumedate` date default NULL,
163 `volumedesc` text, -- volume information (MARC21 362$a)
164 `collectiontitle` mediumtext default NULL,
165 `collectionissn` text default NULL,
166 `collectionvolume` mediumtext default NULL,
167 `editionstatement` text default NULL,
168 `editionresponsibility` text default NULL,
169 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
170 `illus` varchar(255) default NULL, -- illustrations (MARC21 300$b)
171 `pages` varchar(255) default NULL, -- number of pages (MARC21 300$c)
173 `size` varchar(255) default NULL, -- material size (MARC21 300$c)
174 `place` varchar(255) default NULL, -- publication place (MARC21 260$a)
175 `lccn` varchar(25) default NULL, -- library of congress control number (MARC21 010$a)
176 `marc` longblob, -- full bibliographic MARC record
177 `url` text default NULL, -- url (MARC21 856$u)
178 `cn_source` varchar(10) default NULL, -- classification source (MARC21 942$2)
179 `cn_class` varchar(30) default NULL,
180 `cn_item` varchar(10) default NULL,
181 `cn_suffix` varchar(10) default NULL,
182 `cn_sort` varchar(255) default NULL, -- normalized version of the call number used for sorting
183 `agerestriction` varchar(255) default NULL, -- target audience/age restriction from the bib record (MARC21 521$a)
184 `totalissues` int(10),
185 `marcxml` longtext, -- full bibliographic MARC record in MARCXML
186 PRIMARY KEY (`biblioitemnumber`),
187 KEY `bibinoidx` (`biblioitemnumber`),
188 KEY `bibnoidx` (`biblionumber`),
189 KEY `itemtype_idx` (`itemtype`),
190 KEY `isbn` (`isbn`(255)),
191 KEY `issn` (`issn`(255)),
192 KEY `publishercode` (`publishercode`),
193 CONSTRAINT `biblioitems_ibfk_1` FOREIGN KEY (`biblionumber`) REFERENCES `biblio` (`biblionumber`) ON DELETE CASCADE ON UPDATE CASCADE
194 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
197 -- Table structure for table `borrowers`
200 DROP TABLE IF EXISTS `borrowers`;
201 CREATE TABLE `borrowers` ( -- this table includes information about your patrons/borrowers/members
202 `borrowernumber` int(11) NOT NULL auto_increment, -- primary key, Koha assigned ID number for patrons/borrowers
203 `cardnumber` varchar(16) default NULL, -- unique key, library assigned ID number for patrons/borrowers
204 `surname` mediumtext NOT NULL, -- patron/borrower's last name (surname)
205 `firstname` text, -- patron/borrower's first name
206 `title` mediumtext, -- patron/borrower's title, for example: Mr. or Mrs.
207 `othernames` mediumtext, -- any other names associated with the patron/borrower
208 `initials` text, -- initials for your patron/borrower
209 `streetnumber` varchar(10) default NULL, -- the house number for your patron/borrower's primary address
210 `streettype` varchar(50) default NULL, -- the street type (Rd., Blvd, etc) for your patron/borrower's primary address
211 `address` mediumtext NOT NULL, -- the first address line for your patron/borrower's primary address
212 `address2` text, -- the second address line for your patron/borrower's primary address
213 `city` mediumtext NOT NULL, -- the city or town for your patron/borrower's primary address
214 `state` text default NULL, -- the state or province for your patron/borrower's primary address
215 `zipcode` varchar(25) default NULL, -- the zip or postal code for your patron/borrower's primary address
216 `country` text, -- the country for your patron/borrower's primary address
217 `email` mediumtext, -- the primary email address for your patron/borrower's primary address
218 `phone` text, -- the primary phone number for your patron/borrower's primary address
219 `mobile` varchar(50) default NULL, -- the other phone number for your patron/borrower's primary address
220 `fax` mediumtext, -- the fax number for your patron/borrower's primary address
221 `emailpro` text, -- the secondary email addres for your patron/borrower's primary address
222 `phonepro` text, -- the secondary phone number for your patron/borrower's primary address
223 `B_streetnumber` varchar(10) default NULL, -- the house number for your patron/borrower's alternate address
224 `B_streettype` varchar(50) default NULL, -- the street type (Rd., Blvd, etc) for your patron/borrower's alternate address
225 `B_address` varchar(100) default NULL, -- the first address line for your patron/borrower's alternate address
226 `B_address2` text default NULL, -- the second address line for your patron/borrower's alternate address
227 `B_city` mediumtext, -- the city or town for your patron/borrower's alternate address
228 `B_state` text default NULL, -- the state for your patron/borrower's alternate address
229 `B_zipcode` varchar(25) default NULL, -- the zip or postal code for your patron/borrower's alternate address
230 `B_country` text, -- the country for your patron/borrower's alternate address
231 `B_email` text, -- the patron/borrower's alternate email address
232 `B_phone` mediumtext, -- the patron/borrower's alternate phone number
233 `dateofbirth` date default NULL, -- the patron/borrower's date of birth (YYYY-MM-DD)
234 `branchcode` varchar(10) NOT NULL default '', -- foreign key from the branches table, includes the code of the patron/borrower's home branch
235 `categorycode` varchar(10) NOT NULL default '', -- foreign key from the categories table, includes the code of the patron category
236 `dateenrolled` date default NULL, -- date the patron was added to Koha (YYYY-MM-DD)
237 `dateexpiry` date default NULL, -- date the patron/borrower's card is set to expire (YYYY-MM-DD)
238 `gonenoaddress` tinyint(1) default NULL, -- set to 1 for yes and 0 for no, flag to note that library marked this patron/borrower as having an unconfirmed address
239 `lost` tinyint(1) default NULL, -- set to 1 for yes and 0 for no, flag to note that library marked this patron/borrower as having lost their card
240 `debarred` date default NULL, -- until this date the patron can only check-in (no loans, no holds, etc.), is a fine based on days instead of money (YYY-MM-DD)
241 `debarredcomment` VARCHAR(255) DEFAULT NULL, -- comment on the stop of the patron
242 `contactname` mediumtext, -- used for children and profesionals to include surname or last name of guarentor or organization name
243 `contactfirstname` text, -- used for children to include first name of guarentor
244 `contacttitle` text, -- used for children to include title (Mr., Mrs., etc) of guarentor
245 `guarantorid` int(11) default NULL, -- borrowernumber used for children or professionals to link them to guarentors or organizations
246 `borrowernotes` mediumtext, -- a note on the patron/borroewr's account that is only visible in the staff client
247 `relationship` varchar(100) default NULL, -- used for children to include the relationship to their guarentor
248 `ethnicity` varchar(50) default NULL, -- unused in Koha
249 `ethnotes` varchar(255) default NULL, -- unused in Koha
250 `sex` varchar(1) default NULL, -- patron/borrower's gender
251 `password` varchar(60) default NULL, -- patron/borrower's encrypted password
252 `flags` int(11) default NULL, -- will include a number associated with the staff member's permissions
253 `userid` varchar(75) default NULL, -- patron/borrower's opac and/or staff client log in
254 `opacnote` mediumtext, -- a note on the patron/borrower's account that is visible in the OPAC and staff client
255 `contactnote` varchar(255) default NULL, -- a note related to the patron/borrower's alternate address
256 `sort1` varchar(80) default NULL, -- a field that can be used for any information unique to the library
257 `sort2` varchar(80) default NULL, -- a field that can be used for any information unique to the library
258 `altcontactfirstname` varchar(255) default NULL, -- first name of alternate contact for the patron/borrower
259 `altcontactsurname` varchar(255) default NULL, -- surname or last name of the alternate contact for the patron/borrower
260 `altcontactaddress1` varchar(255) default NULL, -- the first address line for the alternate contact for the patron/borrower
261 `altcontactaddress2` varchar(255) default NULL, -- the second address line for the alternate contact for the patron/borrower
262 `altcontactaddress3` varchar(255) default NULL, -- the city for the alternate contact for the patron/borrower
263 `altcontactstate` text default NULL, -- the state for the alternate contact for the patron/borrower
264 `altcontactzipcode` varchar(50) default NULL, -- the zipcode for the alternate contact for the patron/borrower
265 `altcontactcountry` text default NULL, -- the country for the alternate contact for the patron/borrower
266 `altcontactphone` varchar(50) default NULL, -- the phone number for the alternate contact for the patron/borrower
267 `smsalertnumber` varchar(50) default NULL, -- the mobile phone number where the patron/borrower would like to receive notices (if SNS turned on)
268 `privacy` integer(11) DEFAULT '1' NOT NULL, -- patron/borrower's privacy settings related to their reading history
269 UNIQUE KEY `cardnumber` (`cardnumber`),
270 PRIMARY KEY `borrowernumber` (`borrowernumber`),
271 KEY `categorycode` (`categorycode`),
272 KEY `branchcode` (`branchcode`),
273 UNIQUE KEY `userid` (`userid`),
274 KEY `guarantorid` (`guarantorid`),
275 KEY `surname_idx` (`surname`(255)),
276 KEY `firstname_idx` (`firstname`(255)),
277 KEY `othernames_idx` (`othernames`(255)),
278 CONSTRAINT `borrowers_ibfk_1` FOREIGN KEY (`categorycode`) REFERENCES `categories` (`categorycode`),
279 CONSTRAINT `borrowers_ibfk_2` FOREIGN KEY (`branchcode`) REFERENCES `branches` (`branchcode`)
280 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
283 -- Table structure for table `borrower_attribute_types`
286 DROP TABLE IF EXISTS `borrower_attribute_types`;
287 CREATE TABLE `borrower_attribute_types` ( -- definitions for custom patron fields known as extended patron attributes
288 `code` varchar(10) NOT NULL, -- unique key used to identify each custom field
289 `description` varchar(255) NOT NULL, -- description for each custom field
290 `repeatable` tinyint(1) NOT NULL default 0, -- defines whether one patron/borrower can have multiple values for this custom field (1 for yes, 0 for no)
291 `unique_id` tinyint(1) NOT NULL default 0, -- defines if this value needs to be unique (1 for yes, 0 for no)
292 `opac_display` tinyint(1) NOT NULL default 0, -- defines if this field is visible to patrons on their account in the OPAC (1 for yes, 0 for no)
293 `password_allowed` tinyint(1) NOT NULL default 0, -- defines if it is possible to associate a password with this custom field (1 for yes, 0 for no)
294 `staff_searchable` tinyint(1) NOT NULL default 0, -- defines if this field is searchable via the patron search in the staff client (1 for yes, 0 for no)
295 `authorised_value_category` varchar(32) default NULL, -- foreign key from authorised_values that links this custom field to an authorized value category
296 `display_checkout` tinyint(1) NOT NULL default 0,-- defines if this field displays in checkout screens
297 `category_code` VARCHAR(10) NULL DEFAULT NULL,-- defines a category for an attribute_type
298 `class` VARCHAR(255) NOT NULL DEFAULT '',-- defines a class for an attribute_type
299 PRIMARY KEY (`code`),
300 KEY `auth_val_cat_idx` (`authorised_value_category`)
301 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
304 -- Table structure for table `borrower_attributes`
307 DROP TABLE IF EXISTS `borrower_attributes`;
308 CREATE TABLE `borrower_attributes` ( -- values of custom patron fields known as extended patron attributes linked to patrons/borrowers
309 `borrowernumber` int(11) NOT NULL, -- foreign key from the borrowers table, defines which patron/borrower has this attribute
310 `code` varchar(10) NOT NULL, -- foreign key from the borrower_attribute_types table, defines which custom field this value was entered for
311 `attribute` varchar(255) default NULL, -- custom patron field value
312 `password` varchar(64) default NULL, -- password associated with this field
313 KEY `borrowernumber` (`borrowernumber`),
314 KEY `code_attribute` (`code`, `attribute`),
315 CONSTRAINT `borrower_attributes_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`)
316 ON DELETE CASCADE ON UPDATE CASCADE,
317 CONSTRAINT `borrower_attributes_ibfk_2` FOREIGN KEY (`code`) REFERENCES `borrower_attribute_types` (`code`)
318 ON DELETE CASCADE ON UPDATE CASCADE
319 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
322 -- Table structure for table `borrower_debarments`
325 DROP TABLE IF EXISTS `borrower_debarments`;
326 CREATE TABLE borrower_debarments ( -- tracks restrictions on the patron's record
327 borrower_debarment_id int(11) NOT NULL AUTO_INCREMENT, -- unique key for the restriction
328 borrowernumber int(11) NOT NULL, -- foreign key for borrowers.borrowernumber for patron who is restricted
329 expiration date DEFAULT NULL, -- expiration date of the restriction
330 `type` enum('SUSPENSION','OVERDUES','MANUAL','DISCHARGE') NOT NULL DEFAULT 'MANUAL', -- type of restriction
331 `comment` text, -- comments about the restriction
332 manager_id int(11) DEFAULT NULL, -- foreign key for borrowers.borrowernumber for the librarian managing the restriction
333 created timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, -- date the restriction was added
334 updated timestamp NULL DEFAULT NULL, -- date the restriction was updated
335 PRIMARY KEY (borrower_debarment_id),
336 KEY borrowernumber (borrowernumber),
337 CONSTRAINT `borrower_debarments_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`)
338 ON DELETE CASCADE ON UPDATE CASCADE
339 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
343 -- Table structure for table `branch_item_rules`
346 DROP TABLE IF EXISTS `branch_item_rules`;
347 CREATE TABLE `branch_item_rules` ( -- information entered in the circulation and fine rules under 'Holds policy by item type'
348 `branchcode` varchar(10) NOT NULL, -- the branch this rule is for (branches.branchcode)
349 `itemtype` varchar(10) NOT NULL, -- the item type this rule applies to (items.itype)
350 `holdallowed` tinyint(1) default NULL, -- the number of holds allowed
351 `returnbranch` varchar(15) default NULL, -- the branch the item returns to (homebranch, holdingbranch, noreturn)
352 PRIMARY KEY (`itemtype`,`branchcode`),
353 KEY `branch_item_rules_ibfk_2` (`branchcode`),
354 CONSTRAINT `branch_item_rules_ibfk_1` FOREIGN KEY (`itemtype`) REFERENCES `itemtypes` (`itemtype`)
355 ON DELETE CASCADE ON UPDATE CASCADE,
356 CONSTRAINT `branch_item_rules_ibfk_2` FOREIGN KEY (`branchcode`) REFERENCES `branches` (`branchcode`)
357 ON DELETE CASCADE ON UPDATE CASCADE
358 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
361 -- Table structure for table borrower_sync
364 CREATE TABLE borrower_sync (
365 borrowersyncid int(11) NOT NULL AUTO_INCREMENT, -- Primary key, unique identifier
366 borrowernumber int(11) NOT NULL, -- Connects data about synchronisations to a borrower
367 synctype varchar(32) NOT NULL, -- There could potentially be more than one kind of syncing going on, a text string here can be used to tell them apart. E.g.: The Norwegian national patron database uses 'norwegianpatrondb' in this column
368 sync tinyint(1) NOT NULL DEFAULT '0', -- A boolean (1/0) for turning syncing off and on for individual borrowers
369 syncstatus varchar(10) DEFAULT NULL, -- The sync status for any given borrower. Could be text strings like 'new', 'edited', 'synced' etc. The values used here will depend on the actual syncing being done.
370 lastsync varchar(50) DEFAULT NULL, -- Date of the last successfull sync. The date format might be different depending on the service that is being used, so no special date format is being enforced here.
371 hashed_pin varchar(64) DEFAULT NULL, -- Perhaps specific to The Norwegian national patron database, this column holds a hashed PIN code
372 PRIMARY KEY (borrowersyncid),
373 KEY borrowernumber (borrowernumber),
374 CONSTRAINT borrower_sync_ibfk_1 FOREIGN KEY (borrowernumber) REFERENCES borrowers (borrowernumber) ON DELETE CASCADE ON UPDATE CASCADE
375 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
379 -- Table structure for table `branchcategories`
382 DROP TABLE IF EXISTS `branchcategories`;
383 CREATE TABLE `branchcategories` ( -- information related to library/branch groups
384 `categorycode` varchar(10) NOT NULL default '', -- unique identifier for the library/branch group
385 `categoryname` varchar(32), -- name of the library/branch group
386 `codedescription` mediumtext, -- longer description of the library/branch group
387 `categorytype` varchar(16), -- says whether this is a search group or a properties group
388 `show_in_pulldown` tinyint(1) NOT NULL DEFAULT '0', -- says this group should be in the opac libararies pulldown if it is enabled
389 PRIMARY KEY (`categorycode`),
390 KEY `show_in_pulldown` (`show_in_pulldown`)
391 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
394 -- Table structure for table `branches`
397 DROP TABLE IF EXISTS `branches`;
398 CREATE TABLE `branches` ( -- information about your libraries or branches are stored here
399 `branchcode` varchar(10) NOT NULL default '', -- a unique key assigned to each branch
400 `branchname` mediumtext NOT NULL, -- the name of your library or branch
401 `branchaddress1` mediumtext, -- the first address line of for your library or branch
402 `branchaddress2` mediumtext, -- the second address line of for your library or branch
403 `branchaddress3` mediumtext, -- the third address line of for your library or branch
404 `branchzip` varchar(25) default NULL, -- the zip or postal code for your library or branch
405 `branchcity` mediumtext, -- the city or province for your library or branch
406 `branchstate` mediumtext, -- the state for your library or branch
407 `branchcountry` text, -- the county for your library or branch
408 `branchphone` mediumtext, -- the primary phone for your library or branch
409 `branchfax` mediumtext, -- the fax number for your library or branch
410 `branchemail` mediumtext, -- the primary email address for your library or branch
411 `branchreplyto` mediumtext, -- the email to be used as a Reply-To
412 `branchreturnpath` mediumtext, -- the email to be used as Return-Path
413 `branchurl` mediumtext, -- the URL for your library or branch's website
414 `issuing` tinyint(4) default NULL, -- unused in Koha
415 `branchip` varchar(15) default NULL, -- the IP address for your library or branch
416 `branchprinter` varchar(100) default NULL, -- unused in Koha
417 `branchnotes` mediumtext, -- notes related to your library or branch
418 opac_info text, -- HTML that displays in OPAC
419 PRIMARY KEY (`branchcode`)
420 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
423 -- Table structure for table `branchrelations`
426 DROP TABLE IF EXISTS `branchrelations`;
427 CREATE TABLE `branchrelations` ( -- this table links libraries/branches to groups
428 `branchcode` varchar(10) NOT NULL default '', -- foreign key from the branches table to identify the branch
429 `categorycode` varchar(10) NOT NULL default '', -- foreign key from the branchcategories table to identify the group
430 PRIMARY KEY (`branchcode`,`categorycode`),
431 KEY `branchcode` (`branchcode`),
432 KEY `categorycode` (`categorycode`),
433 CONSTRAINT `branchrelations_ibfk_1` FOREIGN KEY (`branchcode`) REFERENCES `branches` (`branchcode`) ON DELETE CASCADE ON UPDATE CASCADE,
434 CONSTRAINT `branchrelations_ibfk_2` FOREIGN KEY (`categorycode`) REFERENCES `branchcategories` (`categorycode`) ON DELETE CASCADE ON UPDATE CASCADE
435 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
438 -- Table structure for table `branchtransfers`
441 DROP TABLE IF EXISTS `branchtransfers`;
442 CREATE TABLE `branchtransfers` ( -- information for items that are in transit between branches
443 `itemnumber` int(11) NOT NULL default 0, -- the itemnumber that it is in transit (items.itemnumber)
444 `datesent` datetime default NULL, -- the date the transfer was initialized
445 `frombranch` varchar(10) NOT NULL default '', -- the branch the transfer is coming from
446 `datearrived` datetime default NULL, -- the date the transfer arrived at its destination
447 `tobranch` varchar(10) NOT NULL default '', -- the branch the transfer was going to
448 `comments` mediumtext, -- any comments related to the transfer
449 KEY `frombranch` (`frombranch`),
450 KEY `tobranch` (`tobranch`),
451 KEY `itemnumber` (`itemnumber`),
452 CONSTRAINT `branchtransfers_ibfk_1` FOREIGN KEY (`frombranch`) REFERENCES `branches` (`branchcode`) ON DELETE CASCADE ON UPDATE CASCADE,
453 CONSTRAINT `branchtransfers_ibfk_2` FOREIGN KEY (`tobranch`) REFERENCES `branches` (`branchcode`) ON DELETE CASCADE ON UPDATE CASCADE,
454 CONSTRAINT `branchtransfers_ibfk_3` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`) ON DELETE CASCADE ON UPDATE CASCADE
455 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
459 -- Table structure for table `browser`
461 DROP TABLE IF EXISTS `browser`;
462 CREATE TABLE `browser` (
463 `level` int(11) NOT NULL,
464 `classification` varchar(20) NOT NULL,
465 `description` varchar(255) NOT NULL,
466 `number` bigint(20) NOT NULL,
467 `endnode` tinyint(4) NOT NULL
468 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
471 -- Table structure for table `categories`
474 DROP TABLE IF EXISTS `categories`;
475 CREATE TABLE `categories` ( -- this table shows information related to Koha patron categories
476 `categorycode` varchar(10) NOT NULL default '', -- unique primary key used to idenfity the patron category
477 `description` mediumtext, -- description of the patron category
478 `enrolmentperiod` smallint(6) default NULL, -- number of months the patron is enrolled for (will be NULL if enrolmentperioddate is set)
479 `enrolmentperioddate` DATE NULL DEFAULT NULL, -- date the patron is enrolled until (will be NULL if enrolmentperiod is set)
480 `upperagelimit` smallint(6) default NULL, -- age limit for the patron
481 `dateofbirthrequired` tinyint(1) default NULL, -- the minimum age required for the patron category
482 `finetype` varchar(30) default NULL, -- unused in Koha
483 `bulk` tinyint(1) default NULL,
484 `enrolmentfee` decimal(28,6) default NULL, -- enrollment fee for the patron
485 `overduenoticerequired` tinyint(1) default NULL, -- are overdue notices sent to this patron category (1 for yes, 0 for no)
486 `issuelimit` smallint(6) default NULL, -- unused in Koha
487 `reservefee` decimal(28,6) default NULL, -- cost to place holds
488 `hidelostitems` tinyint(1) NOT NULL default '0', -- are lost items shown to this category (1 for yes, 0 for no)
489 `category_type` varchar(1) NOT NULL default 'A', -- type of Koha patron (Adult, Child, Professional, Organizational, Statistical, Staff)
490 `BlockExpiredPatronOpacActions` tinyint(1) NOT NULL default '-1', -- wheither or not a patron of this category can renew books or place holds once their card has expired. 0 means they can, 1 means they cannot, -1 means use syspref BlockExpiredPatronOpacActions
491 `default_privacy` ENUM( 'default', 'never', 'forever' ) NOT NULL DEFAULT 'default', -- Default privacy setting for this patron category
492 PRIMARY KEY (`categorycode`),
493 UNIQUE KEY `categorycode` (`categorycode`)
494 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
497 -- Table: collections
499 DROP TABLE IF EXISTS collections;
500 CREATE TABLE collections (
501 colId integer(11) NOT NULL auto_increment,
502 colTitle varchar(100) NOT NULL DEFAULT '',
503 colDesc text NOT NULL,
504 colBranchcode varchar(10) DEFAULT NULL, -- 'branchcode for branch where item should be held.'
506 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
509 -- Constraints for table `collections`
511 ALTER TABLE `collections`
512 ADD CONSTRAINT `collections_ibfk_1` FOREIGN KEY (`colBranchcode`) REFERENCES `branches` (`branchcode`) ON DELETE CASCADE ON UPDATE CASCADE;
515 -- Table: collections_tracking
517 DROP TABLE IF EXISTS collections_tracking;
518 CREATE TABLE collections_tracking (
519 collections_tracking_id integer(11) NOT NULL auto_increment,
520 colId integer(11) NOT NULL DEFAULT 0 comment 'collections.colId',
521 itemnumber integer(11) NOT NULL DEFAULT 0 comment 'items.itemnumber',
522 PRIMARY KEY (collections_tracking_id)
523 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
526 -- Table structure for table `courses`
529 -- The courses table stores the courses created for the
530 -- course reserves feature.
532 DROP TABLE IF EXISTS courses;
533 CREATE TABLE `courses` (
534 `course_id` int(11) NOT NULL AUTO_INCREMENT, -- unique id for the course
535 `department` varchar(80) DEFAULT NULL, -- the authorised value for the DEPARTMENT
536 `course_number` varchar(255) DEFAULT NULL, -- the "course number" assigned to a course
537 `section` varchar(255) DEFAULT NULL, -- the 'section' of a course
538 `course_name` varchar(255) DEFAULT NULL, -- the name of the course
539 `term` varchar(80) DEFAULT NULL, -- the authorised value for the TERM
540 `staff_note` mediumtext, -- the text of the staff only note
541 `public_note` mediumtext, -- the text of the public / opac note
542 `students_count` varchar(20) DEFAULT NULL, -- how many students will be taking this course/section
543 `enabled` enum('yes','no') NOT NULL DEFAULT 'yes', -- determines whether the course is active
544 `timestamp` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
545 PRIMARY KEY (`course_id`)
546 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
549 -- Table structure for table `course_instructors`
552 -- The course instructors table links Koha borrowers to the
553 -- courses they are teaching. Many instructors can teach many
554 -- courses. course_instructors is just a many-to-many join table.
556 DROP TABLE IF EXISTS course_instructors;
557 CREATE TABLE `course_instructors` (
558 `course_id` int(11) NOT NULL, -- foreign key to link to courses.course_id
559 `borrowernumber` int(11) NOT NULL, -- foreign key to link to borrowers.borrowernumber for instructor information
560 PRIMARY KEY (`course_id`,`borrowernumber`),
561 KEY `borrowernumber` (`borrowernumber`)
562 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
565 -- Constraints for table `course_instructors`
567 ALTER TABLE `course_instructors`
568 ADD CONSTRAINT `course_instructors_ibfk_2` FOREIGN KEY (`course_id`) REFERENCES `courses` (`course_id`),
569 ADD CONSTRAINT `course_instructors_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE;
572 -- Table structure for table `course_items`
575 -- If an item is placed on course reserve for one or more courses
576 -- it will have an entry in this table. No matter how many courses an item
577 -- is part of, it will only have one row in this table.
579 DROP TABLE IF EXISTS course_items;
580 CREATE TABLE `course_items` (
581 `ci_id` int(11) NOT NULL AUTO_INCREMENT, -- course item id
582 `itemnumber` int(11) NOT NULL, -- items.itemnumber for the item on reserve
583 `itype` varchar(10) DEFAULT NULL, -- new itemtype for the item to have while on reserve (optional)
584 `ccode` varchar(10) DEFAULT NULL, -- new category code for the item to have while on reserve (optional)
585 `holdingbranch` varchar(10) DEFAULT NULL, -- new holding branch for the item to have while on reserve (optional)
586 `location` varchar(80) DEFAULT NULL, -- new shelving location for the item to have while on reseve (optional)
587 `enabled` enum('yes','no') NOT NULL DEFAULT 'no', -- if at least one enabled course has this item on reseve, this field will be 'yes', otherwise it will be 'no'
588 `timestamp` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
589 PRIMARY KEY (`ci_id`),
590 UNIQUE KEY `itemnumber` (`itemnumber`),
591 KEY `holdingbranch` (`holdingbranch`)
592 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
595 -- Constraints for table `course_items`
597 ALTER TABLE `course_items`
598 ADD CONSTRAINT `course_items_ibfk_2` FOREIGN KEY (`holdingbranch`) REFERENCES `branches` (`branchcode`) ON DELETE CASCADE ON UPDATE CASCADE,
599 ADD CONSTRAINT `course_items_ibfk_1` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`) ON DELETE CASCADE ON UPDATE CASCADE;
602 -- Table structure for table `course_reserves`
605 -- This table connects an item placed on course reserve to a course it is on reserve for.
606 -- There will be a row in this table for each course an item is on reserve for.
608 DROP TABLE IF EXISTS course_reserves;
609 CREATE TABLE `course_reserves` (
610 `cr_id` int(11) NOT NULL AUTO_INCREMENT,
611 `course_id` int(11) NOT NULL, -- foreign key to link to courses.course_id
612 `ci_id` int(11) NOT NULL, -- foreign key to link to courses_items.ci_id
613 `staff_note` mediumtext, -- staff only note
614 `public_note` mediumtext, -- public, OPAC visible note
615 `timestamp` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
616 PRIMARY KEY (`cr_id`),
617 UNIQUE KEY `pseudo_key` (`course_id`,`ci_id`),
618 KEY `course_id` (`course_id`)
619 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
622 -- Constraints for table `course_reserves`
624 ALTER TABLE `course_reserves`
625 ADD CONSTRAINT `course_reserves_ibfk_1` FOREIGN KEY (`course_id`) REFERENCES `courses` (`course_id`);
628 -- Table structure for table `branch_borrower_circ_rules`
631 DROP TABLE IF EXISTS `branch_borrower_circ_rules`;
632 CREATE TABLE `branch_borrower_circ_rules` ( -- includes default circulation rules for patron categories found under "Checkout limit by patron category"
633 `branchcode` VARCHAR(10) NOT NULL, -- the branch this rule applies to (branches.branchcode)
634 `categorycode` VARCHAR(10) NOT NULL, -- the patron category this rule applies to (categories.categorycode)
635 `maxissueqty` int(4) default NULL, -- the maximum number of checkouts this patron category can have at this branch
636 PRIMARY KEY (`categorycode`, `branchcode`),
637 CONSTRAINT `branch_borrower_circ_rules_ibfk_1` FOREIGN KEY (`categorycode`) REFERENCES `categories` (`categorycode`)
638 ON DELETE CASCADE ON UPDATE CASCADE,
639 CONSTRAINT `branch_borrower_circ_rules_ibfk_2` FOREIGN KEY (`branchcode`) REFERENCES `branches` (`branchcode`)
640 ON DELETE CASCADE ON UPDATE CASCADE
641 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
644 -- Table structure for table `default_borrower_circ_rules`
647 DROP TABLE IF EXISTS `default_borrower_circ_rules`;
648 CREATE TABLE `default_borrower_circ_rules` ( -- default checkout rules found under "Default checkout, hold and return policy"
649 `categorycode` VARCHAR(10) NOT NULL, -- patron category this rul
650 `maxissueqty` int(4) default NULL,
651 PRIMARY KEY (`categorycode`),
652 CONSTRAINT `borrower_borrower_circ_rules_ibfk_1` FOREIGN KEY (`categorycode`) REFERENCES `categories` (`categorycode`)
653 ON DELETE CASCADE ON UPDATE CASCADE
654 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
657 -- Table structure for table `default_branch_circ_rules`
660 DROP TABLE IF EXISTS `default_branch_circ_rules`;
661 CREATE TABLE `default_branch_circ_rules` (
662 `branchcode` VARCHAR(10) NOT NULL,
663 `maxissueqty` int(4) default NULL,
664 `holdallowed` tinyint(1) default NULL,
665 `returnbranch` varchar(15) default NULL,
666 PRIMARY KEY (`branchcode`),
667 CONSTRAINT `default_branch_circ_rules_ibfk_1` FOREIGN KEY (`branchcode`) REFERENCES `branches` (`branchcode`)
668 ON DELETE CASCADE ON UPDATE CASCADE
669 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
672 -- Table structure for table `default_branch_item_rules`
674 DROP TABLE IF EXISTS `default_branch_item_rules`;
675 CREATE TABLE `default_branch_item_rules` (
676 `itemtype` varchar(10) NOT NULL,
677 `holdallowed` tinyint(1) default NULL,
678 `returnbranch` varchar(15) default NULL,
679 PRIMARY KEY (`itemtype`),
680 CONSTRAINT `default_branch_item_rules_ibfk_1` FOREIGN KEY (`itemtype`) REFERENCES `itemtypes` (`itemtype`)
681 ON DELETE CASCADE ON UPDATE CASCADE
682 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
685 -- Table structure for table `default_circ_rules`
688 DROP TABLE IF EXISTS `default_circ_rules`;
689 CREATE TABLE `default_circ_rules` (
690 `singleton` enum('singleton') NOT NULL default 'singleton',
691 `maxissueqty` int(4) default NULL,
692 `holdallowed` int(1) default NULL,
693 `returnbranch` varchar(15) default NULL,
694 PRIMARY KEY (`singleton`)
695 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
698 -- Table structure for table `cities`
701 DROP TABLE IF EXISTS `cities`;
702 CREATE TABLE `cities` ( -- authorized values for cities/states/countries to choose when adding/editing a patron/borrower
703 `cityid` int(11) NOT NULL auto_increment, -- unique identifier added by Koha
704 `city_name` varchar(100) NOT NULL default '', -- name of the city
705 `city_state` VARCHAR( 100 ) NULL DEFAULT NULL, -- name of the state/province
706 `city_country` VARCHAR( 100 ) NULL DEFAULT NULL, -- name of the country
707 `city_zipcode` varchar(20) default NULL, -- zip or postal code
708 PRIMARY KEY (`cityid`)
709 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
712 -- Table structure for table `class_sort_rules`
715 DROP TABLE IF EXISTS `class_sort_rules`;
716 CREATE TABLE `class_sort_rules` (
717 `class_sort_rule` varchar(10) NOT NULL default '',
718 `description` mediumtext,
719 `sort_routine` varchar(30) NOT NULL default '',
720 PRIMARY KEY (`class_sort_rule`),
721 UNIQUE KEY `class_sort_rule_idx` (`class_sort_rule`)
722 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
725 -- Table structure for table `class_sources`
728 DROP TABLE IF EXISTS `class_sources`;
729 CREATE TABLE `class_sources` (
730 `cn_source` varchar(10) NOT NULL default '',
731 `description` mediumtext,
732 `used` tinyint(4) NOT NULL default 0,
733 `class_sort_rule` varchar(10) NOT NULL default '',
734 PRIMARY KEY (`cn_source`),
735 UNIQUE KEY `cn_source_idx` (`cn_source`),
736 KEY `used_idx` (`used`),
737 CONSTRAINT `class_source_ibfk_1` FOREIGN KEY (`class_sort_rule`) REFERENCES `class_sort_rules` (`class_sort_rule`)
738 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
741 -- Table structure for table `currency`
744 DROP TABLE IF EXISTS `currency`;
745 CREATE TABLE `currency` (
746 `currency` varchar(10) NOT NULL default '',
747 `symbol` varchar(5) default NULL,
748 `isocode` varchar(5) default NULL,
749 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
750 `rate` float(15,5) default NULL,
751 `active` tinyint(1) default NULL,
752 PRIMARY KEY (`currency`)
753 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
756 -- Table structure for table `deletedbiblio`
759 DROP TABLE IF EXISTS `deletedbiblio`;
760 CREATE TABLE `deletedbiblio` ( -- stores information about bibliographic records that have been deleted
761 `biblionumber` int(11) NOT NULL auto_increment, -- unique identifier assigned to each bibliographic record
762 `frameworkcode` varchar(4) NOT NULL default '', -- foriegn key from the biblio_framework table to identify which framework was used in cataloging this record
763 `author` mediumtext, -- statement of responsibility from MARC record (100$a in MARC21)
764 `title` mediumtext, -- title (without the subtitle) from the MARC record (245$a in MARC21)
765 `unititle` mediumtext, -- uniform title (without the subtitle) from the MARC record (240$a in MARC21)
766 `notes` mediumtext, -- values from the general notes field in the MARC record (500$a in MARC21) split by bar (|)
767 `serial` tinyint(1) default NULL, -- Boolean indicating whether biblio is for a serial
768 `seriestitle` mediumtext,
769 `copyrightdate` smallint(6) default NULL, -- publication or copyright date from the MARC record
770 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- date and time this record was last touched
771 `datecreated` DATE NOT NULL, -- the date this record was added to Koha
772 `abstract` mediumtext, -- summary from the MARC record (520$a in MARC21)
773 PRIMARY KEY (`biblionumber`),
774 KEY `blbnoidx` (`biblionumber`)
775 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
778 -- Table structure for table `deletedbiblioitems`
781 DROP TABLE IF EXISTS `deletedbiblioitems`;
782 CREATE TABLE `deletedbiblioitems` ( -- information about bibliographic records that have been deleted
783 `biblioitemnumber` int(11) NOT NULL default 0, -- primary key, unique identifier assigned by Koha
784 `biblionumber` int(11) NOT NULL default 0, -- foreign key linking this table to the biblio table
787 `itemtype` varchar(10) default NULL, -- biblio level item type (MARC21 942$c)
788 `isbn` mediumtext default NULL, -- ISBN (MARC21 020$a)
789 `issn` mediumtext default NULL, -- ISSN (MARC21 022$a)
790 `ean` varchar(13) default NULL,
791 `publicationyear` text,
792 `publishercode` varchar(255) default NULL, -- publisher (MARC21 260$b)
793 `volumedate` date default NULL,
794 `volumedesc` text, -- volume information (MARC21 362$a)
795 `collectiontitle` mediumtext default NULL,
796 `collectionissn` text default NULL,
797 `collectionvolume` mediumtext default NULL,
798 `editionstatement` text default NULL,
799 `editionresponsibility` text default NULL,
800 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
801 `illus` varchar(255) default NULL, -- illustrations (MARC21 300$b)
802 `pages` varchar(255) default NULL, -- number of pages (MARC21 300$c)
804 `size` varchar(255) default NULL, -- material size (MARC21 300$c)
805 `place` varchar(255) default NULL, -- publication place (MARC21 260$a)
806 `lccn` varchar(25) default NULL, -- library of congress control number (MARC21 010$a)
807 `marc` longblob, -- full bibliographic MARC record
808 `url` text default NULL, -- url (MARC21 856$u)
809 `cn_source` varchar(10) default NULL, -- classification source (MARC21 942$2)
810 `cn_class` varchar(30) default NULL,
811 `cn_item` varchar(10) default NULL,
812 `cn_suffix` varchar(10) default NULL,
813 `cn_sort` varchar(255) default NULL, -- normalized version of the call number used for sorting
814 `agerestriction` varchar(255) default NULL, -- target audience/age restriction from the bib record (MARC21 521$a)
815 `totalissues` int(10),
816 `marcxml` longtext, -- full bibliographic MARC record in MARCXML
817 PRIMARY KEY (`biblioitemnumber`),
818 KEY `bibinoidx` (`biblioitemnumber`),
819 KEY `bibnoidx` (`biblionumber`),
820 KEY `itemtype_idx` (`itemtype`),
821 KEY `isbn` (`isbn`(255)),
822 KEY `publishercode` (`publishercode`)
823 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
826 -- Table structure for table `deletedborrowers`
829 DROP TABLE IF EXISTS `deletedborrowers`;
830 CREATE TABLE `deletedborrowers` ( -- stores data related to the patrons/borrowers you have deleted
831 `borrowernumber` int(11) NOT NULL default 0, -- primary key, Koha assigned ID number for patrons/borrowers
832 `cardnumber` varchar(16) default NULL, -- unique key, library assigned ID number for patrons/borrowers
833 `surname` mediumtext NOT NULL, -- patron/borrower's last name (surname)
834 `firstname` text, -- patron/borrower's first name
835 `title` mediumtext, -- patron/borrower's title, for example: Mr. or Mrs.
836 `othernames` mediumtext, -- any other names associated with the patron/borrower
837 `initials` text, -- initials for your patron/borrower
838 `streetnumber` varchar(10) default NULL, -- the house number for your patron/borrower's primary address
839 `streettype` varchar(50) default NULL, -- the street type (Rd., Blvd, etc) for your patron/borrower's primary address
840 `address` mediumtext NOT NULL, -- the first address line for your patron/borrower's primary address
841 `address2` text, -- the second address line for your patron/borrower's primary address
842 `city` mediumtext NOT NULL, -- the city or town for your patron/borrower's primary address
843 `state` text default NULL, -- the state or province for your patron/borrower's primary address
844 `zipcode` varchar(25) default NULL, -- the zip or postal code for your patron/borrower's primary address
845 `country` text, -- the country for your patron/borrower's primary address
846 `email` mediumtext, -- the primary email address for your patron/borrower's primary address
847 `phone` text, -- the primary phone number for your patron/borrower's primary address
848 `mobile` varchar(50) default NULL, -- the other phone number for your patron/borrower's primary address
849 `fax` mediumtext, -- the fax number for your patron/borrower's primary address
850 `emailpro` text, -- the secondary email addres for your patron/borrower's primary address
851 `phonepro` text, -- the secondary phone number for your patron/borrower's primary address
852 `B_streetnumber` varchar(10) default NULL, -- the house number for your patron/borrower's alternate address
853 `B_streettype` varchar(50) default NULL, -- the street type (Rd., Blvd, etc) for your patron/borrower's alternate address
854 `B_address` varchar(100) default NULL, -- the first address line for your patron/borrower's alternate address
855 `B_address2` text default NULL, -- the second address line for your patron/borrower's alternate address
856 `B_city` mediumtext, -- the city or town for your patron/borrower's alternate address
857 `B_state` text default NULL, -- the state for your patron/borrower's alternate address
858 `B_zipcode` varchar(25) default NULL, -- the zip or postal code for your patron/borrower's alternate address
859 `B_country` text, -- the country for your patron/borrower's alternate address
860 `B_email` text, -- the patron/borrower's alternate email address
861 `B_phone` mediumtext, -- the patron/borrower's alternate phone number
862 `dateofbirth` date default NULL, -- the patron/borrower's date of birth (YYYY-MM-DD)
863 `branchcode` varchar(10) NOT NULL default '', -- foreign key from the branches table, includes the code of the patron/borrower's home branch
864 `categorycode` varchar(10) NOT NULL default '', -- foreign key from the categories table, includes the code of the patron category
865 `dateenrolled` date default NULL, -- date the patron was added to Koha (YYYY-MM-DD)
866 `dateexpiry` date default NULL, -- date the patron/borrower's card is set to expire (YYYY-MM-DD)
867 `gonenoaddress` tinyint(1) default NULL, -- set to 1 for yes and 0 for no, flag to note that library marked this patron/borrower as having an unconfirmed address
868 `lost` tinyint(1) default NULL, -- set to 1 for yes and 0 for no, flag to note that library marked this patron/borrower as having lost their card
869 `debarred` date default NULL, -- until this date the patron can only check-in (no loans, no holds, etc.), is a fine based on days instead of money (YYY-MM-DD)
870 `debarredcomment` VARCHAR(255) DEFAULT NULL, -- comment on the stop of patron
871 `contactname` mediumtext, -- used for children and profesionals to include surname or last name of guarentor or organization name
872 `contactfirstname` text, -- used for children to include first name of guarentor
873 `contacttitle` text, -- used for children to include title (Mr., Mrs., etc) of guarentor
874 `guarantorid` int(11) default NULL, -- borrowernumber used for children or professionals to link them to guarentors or organizations
875 `borrowernotes` mediumtext, -- a note on the patron/borroewr's account that is only visible in the staff client
876 `relationship` varchar(100) default NULL, -- used for children to include the relationship to their guarentor
877 `ethnicity` varchar(50) default NULL, -- unused in Koha
878 `ethnotes` varchar(255) default NULL, -- unused in Koha
879 `sex` varchar(1) default NULL, -- patron/borrower's gender
880 `password` varchar(30) default NULL, -- patron/borrower's encrypted password
881 `flags` int(11) default NULL, -- will include a number associated with the staff member's permissions
882 `userid` varchar(30) default NULL, -- patron/borrower's opac and/or staff client log in
883 `opacnote` mediumtext, -- a note on the patron/borrower's account that is visible in the OPAC and staff client
884 `contactnote` varchar(255) default NULL, -- a note related to the patron/borrower's alternate address
885 `sort1` varchar(80) default NULL, -- a field that can be used for any information unique to the library
886 `sort2` varchar(80) default NULL, -- a field that can be used for any information unique to the library
887 `altcontactfirstname` varchar(255) default NULL, -- first name of alternate contact for the patron/borrower
888 `altcontactsurname` varchar(255) default NULL, -- surname or last name of the alternate contact for the patron/borrower
889 `altcontactaddress1` varchar(255) default NULL, -- the first address line for the alternate contact for the patron/borrower
890 `altcontactaddress2` varchar(255) default NULL, -- the second address line for the alternate contact for the patron/borrower
891 `altcontactaddress3` varchar(255) default NULL, -- the city for the alternate contact for the patron/borrower
892 `altcontactstate` text default NULL, -- the state for the alternate contact for the patron/borrower
893 `altcontactzipcode` varchar(50) default NULL, -- the zipcode for the alternate contact for the patron/borrower
894 `altcontactcountry` text default NULL, -- the country for the alternate contact for the patron/borrower
895 `altcontactphone` varchar(50) default NULL, -- the phone number for the alternate contact for the patron/borrower
896 `smsalertnumber` varchar(50) default NULL, -- the mobile phone number where the patron/borrower would like to receive notices (if SNS turned on)
897 `privacy` integer(11) DEFAULT '1' NOT NULL, -- patron/borrower's privacy settings related to their reading history KEY `borrowernumber` (`borrowernumber`),
898 KEY borrowernumber (borrowernumber),
899 KEY `cardnumber` (`cardnumber`)
900 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
903 -- Table structure for table `deleteditems`
906 DROP TABLE IF EXISTS `deleteditems`;
907 CREATE TABLE `deleteditems` (
908 `itemnumber` int(11) NOT NULL default 0, -- primary key and unique identifier added by Koha
909 `biblionumber` int(11) NOT NULL default 0, -- foreign key from biblio table used to link this item to the right bib record
910 `biblioitemnumber` int(11) NOT NULL default 0, -- foreign key from the biblioitems table to link to item to additional information
911 `barcode` varchar(20) default NULL, -- item barcode (MARC21 952$p)
912 `dateaccessioned` date default NULL, -- date the item was acquired or added to Koha (MARC21 952$d)
913 `booksellerid` mediumtext default NULL, -- where the item was purchased (MARC21 952$e)
914 `homebranch` varchar(10) default NULL, -- foreign key from the branches table for the library that owns this item (MARC21 952$a)
915 `price` decimal(8,2) default NULL, -- purchase price (MARC21 952$g)
916 `replacementprice` decimal(8,2) default NULL, -- cost the library charges to replace the item if it has been marked lost (MARC21 952$v)
917 `replacementpricedate` date default NULL, -- the date the price is effective from (MARC21 952$w)
918 `datelastborrowed` date default NULL, -- the date the item was last checked out
919 `datelastseen` date default NULL, -- the date the item was last see (usually the last time the barcode was scanned or inventory was done)
920 `stack` tinyint(1) default NULL,
921 `notforloan` tinyint(1) NOT NULL default 0, -- authorized value defining why this item is not for loan (MARC21 952$7)
922 `damaged` tinyint(1) NOT NULL default 0, -- authorized value defining this item as damaged (MARC21 952$4)
923 `itemlost` tinyint(1) NOT NULL default 0, -- authorized value defining this item as lost (MARC21 952$1)
924 `itemlost_on` datetime DEFAULT NULL, -- the date and time an item was last marked as lost, NULL if not lost
925 `withdrawn` tinyint(1) NOT NULL default 0, -- authorized value defining this item as withdrawn (MARC21 952$0)
926 `withdrawn_on` datetime DEFAULT NULL, -- the date and time an item was last marked as withdrawn, NULL if not withdrawn
927 `itemcallnumber` varchar(255) default NULL, -- call number for this item (MARC21 952$o)
928 `coded_location_qualifier` varchar(10) default NULL, -- coded location qualifier(MARC21 952$f)
929 `issues` smallint(6) default NULL, -- number of times this item has been checked out
930 `renewals` smallint(6) default NULL, -- number of times this item has been renewed
931 `reserves` smallint(6) default NULL, -- number of times this item has been placed on hold/reserved
932 `restricted` tinyint(1) default NULL, -- authorized value defining use restrictions for this item (MARC21 952$5)
933 `itemnotes` mediumtext, -- public notes on this item (MARC21 952$x)
934 `itemnotes_nonpublic` mediumtext default NULL,
935 `holdingbranch` varchar(10) default NULL, -- foreign key from the branches table for the library that is currently in possession item (MARC21 952$b)
936 `paidfor` mediumtext,
937 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- date and time this item was last altered
938 `location` varchar(80) default NULL, -- authorized value for the shelving location for this item (MARC21 952$c)
939 `permanent_location` varchar(80) default NULL, -- linked to the CART and PROC temporary locations feature, stores the permanent shelving location
940 `onloan` date default NULL, -- defines if item is checked out (NULL for not checked out, and checkout date for checked out)
941 `cn_source` varchar(10) default NULL, -- classification source used on this item (MARC21 952$2)
942 `cn_sort` varchar(255) default NULL, -- normalized form of the call number (MARC21 952$o) used for sorting
943 `ccode` varchar(10) default NULL, -- authorized value for the collection code associated with this item (MARC21 952$8)
944 `materials` text default NULL, -- materials specified (MARC21 952$3)
945 `uri` varchar(255) default NULL, -- URL for the item (MARC21 952$u)
946 `itype` varchar(10) default NULL, -- foreign key from the itemtypes table defining the type for this item (MARC21 952$y)
947 `more_subfields_xml` longtext default NULL, -- additional 952 subfields in XML format
948 `enumchron` text default NULL, -- serial enumeration/chronology for the item (MARC21 952$h)
949 `copynumber` varchar(32) default NULL, -- copy number (MARC21 952$t)
950 `stocknumber` varchar(32) default NULL, -- inventory number (MARC21 952$i)
951 PRIMARY KEY (`itemnumber`),
952 KEY `delitembarcodeidx` (`barcode`),
953 KEY `delitemstocknumberidx` (`stocknumber`),
954 KEY `delitembinoidx` (`biblioitemnumber`),
955 KEY `delitembibnoidx` (`biblionumber`),
956 KEY `delhomebranch` (`homebranch`),
957 KEY `delholdingbranch` (`holdingbranch`),
958 KEY `itype_idx` (`itype`)
959 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
962 -- Table structure for table `ethnicity`
965 DROP TABLE IF EXISTS `ethnicity`;
966 CREATE TABLE `ethnicity` (
967 `code` varchar(10) NOT NULL default '',
968 `name` varchar(255) default NULL,
970 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
973 -- Table structure for table `export_format`
976 DROP TABLE IF EXISTS `export_format`;
977 CREATE TABLE `export_format` (
978 `export_format_id` int(11) NOT NULL auto_increment,
979 `profile` varchar(255) NOT NULL,
980 `description` mediumtext NOT NULL,
981 `content` mediumtext NOT NULL,
982 `csv_separator` varchar(2) NOT NULL,
983 `field_separator` varchar(2) NOT NULL,
984 `subfield_separator` varchar(2) NOT NULL,
985 `encoding` varchar(255) NOT NULL,
986 `type` varchar(255) DEFAULT 'marc',
987 PRIMARY KEY (`export_format_id`)
988 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci COMMENT='Used for CSV export';
992 -- Table structure for table `hold_fill_targets`
995 DROP TABLE IF EXISTS `hold_fill_targets`;
996 CREATE TABLE hold_fill_targets (
997 `borrowernumber` int(11) NOT NULL,
998 `biblionumber` int(11) NOT NULL,
999 `itemnumber` int(11) NOT NULL,
1000 `source_branchcode` varchar(10) default NULL,
1001 `item_level_request` tinyint(4) NOT NULL default 0,
1002 PRIMARY KEY `itemnumber` (`itemnumber`),
1003 KEY `bib_branch` (`biblionumber`, `source_branchcode`),
1004 CONSTRAINT `hold_fill_targets_ibfk_1` FOREIGN KEY (`borrowernumber`)
1005 REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE,
1006 CONSTRAINT `hold_fill_targets_ibfk_2` FOREIGN KEY (`biblionumber`)
1007 REFERENCES `biblio` (`biblionumber`) ON DELETE CASCADE ON UPDATE CASCADE,
1008 CONSTRAINT `hold_fill_targets_ibfk_3` FOREIGN KEY (`itemnumber`)
1009 REFERENCES `items` (`itemnumber`) ON DELETE CASCADE ON UPDATE CASCADE,
1010 CONSTRAINT `hold_fill_targets_ibfk_4` FOREIGN KEY (`source_branchcode`)
1011 REFERENCES `branches` (`branchcode`) ON DELETE CASCADE ON UPDATE CASCADE
1012 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1015 -- Table structure for table `import_batches`
1018 DROP TABLE IF EXISTS `import_batches`;
1019 CREATE TABLE `import_batches` ( -- information about batches of marc records that have been imported
1020 `import_batch_id` int(11) NOT NULL auto_increment, -- unique identifier and primary key
1021 `matcher_id` int(11) default NULL, -- the id of the match rule used (matchpoints.matcher_id)
1022 `template_id` int(11) default NULL,
1023 `branchcode` varchar(10) default NULL,
1024 `num_records` int(11) NOT NULL default 0, -- number of records in the file
1025 `num_items` int(11) NOT NULL default 0, -- number of items in the file
1026 `upload_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP, -- date and time the file was uploaded
1027 `overlay_action` enum('replace', 'create_new', 'use_template', 'ignore') NOT NULL default 'create_new', -- how to handle duplicate records
1028 `nomatch_action` enum('create_new', 'ignore') NOT NULL default 'create_new', -- how to handle records where no match is found
1029 `item_action` enum('always_add', 'add_only_for_matches', 'add_only_for_new', 'ignore', 'replace') NOT NULL default 'always_add', -- what to do with item records
1030 `import_status` enum('staging', 'staged', 'importing', 'imported', 'reverting', 'reverted', 'cleaned') NOT NULL default 'staging', -- the status of the imported file
1031 `batch_type` enum('batch', 'z3950', 'webservice') NOT NULL default 'batch', -- where this batch has come from
1032 `record_type` enum('biblio', 'auth', 'holdings') NOT NULL default 'biblio', -- type of record in the batch
1033 `file_name` varchar(100), -- the name of the file uploaded
1034 `comments` mediumtext, -- any comments added when the file was uploaded
1035 PRIMARY KEY (`import_batch_id`),
1036 KEY `branchcode` (`branchcode`)
1037 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1040 -- Table structure for table `import_records`
1043 DROP TABLE IF EXISTS `import_records`;
1044 CREATE TABLE `import_records` (
1045 `import_record_id` int(11) NOT NULL auto_increment,
1046 `import_batch_id` int(11) NOT NULL,
1047 `branchcode` varchar(10) default NULL,
1048 `record_sequence` int(11) NOT NULL default 0,
1049 `upload_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP,
1050 `import_date` DATE default NULL,
1051 `marc` longblob NOT NULL,
1052 `marcxml` longtext NOT NULL,
1053 `marcxml_old` longtext NOT NULL,
1054 `record_type` enum('biblio', 'auth', 'holdings') NOT NULL default 'biblio',
1055 `overlay_status` enum('no_match', 'auto_match', 'manual_match', 'match_applied') NOT NULL default 'no_match',
1056 `status` enum('error', 'staged', 'imported', 'reverted', 'items_reverted', 'ignored') NOT NULL default 'staged',
1057 `import_error` mediumtext,
1058 `encoding` varchar(40) NOT NULL default '',
1059 `z3950random` varchar(40) default NULL,
1060 PRIMARY KEY (`import_record_id`),
1061 CONSTRAINT `import_records_ifbk_1` FOREIGN KEY (`import_batch_id`)
1062 REFERENCES `import_batches` (`import_batch_id`) ON DELETE CASCADE ON UPDATE CASCADE,
1063 KEY `branchcode` (`branchcode`),
1064 KEY `batch_sequence` (`import_batch_id`, `record_sequence`),
1065 KEY `batch_id_record_type` (`import_batch_id`,`record_type`)
1066 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1069 -- Table structure for `import_record_matches`
1071 DROP TABLE IF EXISTS `import_record_matches`;
1072 CREATE TABLE `import_record_matches` ( -- matches found when importing a batch of records
1073 `import_record_id` int(11) NOT NULL, -- the id given to the imported bib record (import_records.import_record_id)
1074 `candidate_match_id` int(11) NOT NULL, -- the biblio the imported record matches (biblio.biblionumber)
1075 `score` int(11) NOT NULL default 0, -- the match score
1076 CONSTRAINT `import_record_matches_ibfk_1` FOREIGN KEY (`import_record_id`)
1077 REFERENCES `import_records` (`import_record_id`) ON DELETE CASCADE ON UPDATE CASCADE,
1078 KEY `record_score` (`import_record_id`, `score`)
1079 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1082 -- Table structure for table `import_auths`
1085 DROP TABLE IF EXISTS `import_auths`;
1086 CREATE TABLE `import_auths` (
1087 `import_record_id` int(11) NOT NULL,
1088 `matched_authid` int(11) default NULL,
1089 `control_number` varchar(25) default NULL,
1090 `authorized_heading` varchar(128) default NULL,
1091 `original_source` varchar(25) default NULL,
1092 CONSTRAINT `import_auths_ibfk_1` FOREIGN KEY (`import_record_id`)
1093 REFERENCES `import_records` (`import_record_id`) ON DELETE CASCADE ON UPDATE CASCADE,
1094 KEY `matched_authid` (`matched_authid`)
1095 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1098 -- Table structure for table `import_biblios`
1101 DROP TABLE IF EXISTS `import_biblios`;
1102 CREATE TABLE `import_biblios` (
1103 `import_record_id` int(11) NOT NULL,
1104 `matched_biblionumber` int(11) default NULL,
1105 `control_number` varchar(25) default NULL,
1106 `original_source` varchar(25) default NULL,
1107 `title` varchar(128) default NULL,
1108 `author` varchar(80) default NULL,
1109 `isbn` varchar(30) default NULL,
1110 `issn` varchar(9) default NULL,
1111 `has_items` tinyint(1) NOT NULL default 0,
1112 CONSTRAINT `import_biblios_ibfk_1` FOREIGN KEY (`import_record_id`)
1113 REFERENCES `import_records` (`import_record_id`) ON DELETE CASCADE ON UPDATE CASCADE,
1114 KEY `matched_biblionumber` (`matched_biblionumber`),
1115 KEY `title` (`title`),
1117 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1120 -- Table structure for table `import_items`
1123 DROP TABLE IF EXISTS `import_items`;
1124 CREATE TABLE `import_items` (
1125 `import_items_id` int(11) NOT NULL auto_increment,
1126 `import_record_id` int(11) NOT NULL,
1127 `itemnumber` int(11) default NULL,
1128 `branchcode` varchar(10) default NULL,
1129 `status` enum('error', 'staged', 'imported', 'reverted', 'ignored') NOT NULL default 'staged',
1130 `marcxml` longtext NOT NULL,
1131 `import_error` mediumtext,
1132 PRIMARY KEY (`import_items_id`),
1133 CONSTRAINT `import_items_ibfk_1` FOREIGN KEY (`import_record_id`)
1134 REFERENCES `import_records` (`import_record_id`) ON DELETE CASCADE ON UPDATE CASCADE,
1135 KEY `itemnumber` (`itemnumber`),
1136 KEY `branchcode` (`branchcode`)
1137 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1140 -- Table structure for table `issues`
1143 DROP TABLE IF EXISTS `issues`;
1144 CREATE TABLE `issues` ( -- information related to check outs or issues
1145 `issue_id` int(11) NOT NULL AUTO_INCREMENT, -- primary key for issues table
1146 `borrowernumber` int(11), -- foreign key, linking this to the borrowers table for the patron this item was checked out to
1147 `itemnumber` int(11), -- foreign key, linking this to the items table for the item that was checked out
1148 `date_due` datetime default NULL, -- datetime the item is due (yyyy-mm-dd hh:mm::ss)
1149 `branchcode` varchar(10) default NULL, -- foreign key, linking to the branches table for the location the item was checked out
1150 `returndate` datetime default NULL, -- date the item was returned, will be NULL until moved to old_issues
1151 `lastreneweddate` datetime default NULL, -- date the item was last renewed
1152 `return` varchar(4) default NULL,
1153 `renewals` tinyint(4) default NULL, -- lists the number of times the item was renewed
1154 `auto_renew` BOOLEAN default FALSE, -- automatic renewal
1155 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- the date and time this record was last touched
1156 `issuedate` datetime default NULL, -- date the item was checked out or issued
1157 `onsite_checkout` int(1) NOT NULL default 0, -- in house use flag
1158 PRIMARY KEY (`issue_id`),
1159 KEY `issuesborridx` (`borrowernumber`),
1160 KEY `itemnumber_idx` (`itemnumber`),
1161 KEY `branchcode_idx` (`branchcode`),
1162 KEY `bordate` (`borrowernumber`,`timestamp`),
1163 CONSTRAINT `issues_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE RESTRICT ON UPDATE CASCADE,
1164 CONSTRAINT `issues_ibfk_2` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`) ON DELETE RESTRICT ON UPDATE CASCADE
1165 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1168 -- Table structure for table `issuingrules`
1171 DROP TABLE IF EXISTS `issuingrules`;
1172 CREATE TABLE `issuingrules` ( -- circulation and fine rules
1173 `categorycode` varchar(10) NOT NULL default '', -- patron category this rule is for (categories.categorycode)
1174 `itemtype` varchar(10) NOT NULL default '', -- item type this rule is for (itemtypes.itemtype)
1175 `restrictedtype` tinyint(1) default NULL, -- not used? always NULL
1176 `rentaldiscount` decimal(28,6) default NULL, -- percent discount on the rental charge for this item
1177 `reservecharge` decimal(28,6) default NULL,
1178 `fine` decimal(28,6) default NULL, -- fine amount
1179 `finedays` int(11) default NULL, -- suspension in days
1180 `maxsuspensiondays` int(11) default NULL, -- max suspension days
1181 `firstremind` int(11) default NULL, -- fine grace period
1182 `chargeperiod` int(11) default NULL, -- how often the fine amount is charged
1183 `accountsent` int(11) default NULL, -- not used? always NULL
1184 `chargename` varchar(100) default NULL, -- not used? always NULL
1185 `maxissueqty` int(4) default NULL, -- total number of checkouts allowed
1186 `issuelength` int(4) default NULL, -- length of checkout in the unit set in issuingrules.lengthunit
1187 `lengthunit` varchar(10) default 'days', -- unit of checkout length (days, hours)
1188 `hardduedate` date default NULL, -- hard due date
1189 `hardduedatecompare` tinyint NOT NULL default "0", -- type of hard due date (1 = after, 0 = on, -1 = before)
1190 `renewalsallowed` smallint(6) NOT NULL default "0", -- how many renewals are allowed
1191 `renewalperiod` int(4) default NULL, -- renewal period in the unit set in issuingrules.lengthunit
1192 `norenewalbefore` int(4) default NULL, -- no renewal allowed until X days or hours before due date. In the unit set in issuingrules.lengthunit
1193 `auto_renew` BOOLEAN default FALSE, -- automatic renewal
1194 `reservesallowed` smallint(6) NOT NULL default "0", -- how many holds are allowed
1195 `branchcode` varchar(10) NOT NULL default '', -- the branch this rule is for (branches.branchcode)
1196 overduefinescap decimal(28,6) default NULL, -- the maximum amount of an overdue fine
1197 onshelfholds tinyint(1) NOT NULL default 0, -- allow holds for items that are on shelf
1198 opacitemholds char(1) NOT NULL default 'N', -- allow opac users to place specific items on hold
1199 PRIMARY KEY (`branchcode`,`categorycode`,`itemtype`),
1200 KEY `categorycode` (`categorycode`),
1201 KEY `itemtype` (`itemtype`)
1202 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1205 -- Table structure for table `items`
1208 DROP TABLE IF EXISTS `items`;
1209 CREATE TABLE `items` ( -- holdings/item information
1210 `itemnumber` int(11) NOT NULL auto_increment, -- primary key and unique identifier added by Koha
1211 `biblionumber` int(11) NOT NULL default 0, -- foreign key from biblio table used to link this item to the right bib record
1212 `biblioitemnumber` int(11) NOT NULL default 0, -- foreign key from the biblioitems table to link to item to additional information
1213 `barcode` varchar(20) default NULL, -- item barcode (MARC21 952$p)
1214 `dateaccessioned` date default NULL, -- date the item was acquired or added to Koha (MARC21 952$d)
1215 `booksellerid` mediumtext default NULL, -- where the item was purchased (MARC21 952$e)
1216 `homebranch` varchar(10) default NULL, -- foreign key from the branches table for the library that owns this item (MARC21 952$a)
1217 `price` decimal(8,2) default NULL, -- purchase price (MARC21 952$g)
1218 `replacementprice` decimal(8,2) default NULL, -- cost the library charges to replace the item if it has been marked lost (MARC21 952$v)
1219 `replacementpricedate` date default NULL, -- the date the price is effective from (MARC21 952$w)
1220 `datelastborrowed` date default NULL, -- the date the item was last checked out/issued
1221 `datelastseen` date default NULL, -- the date the item was last see (usually the last time the barcode was scanned or inventory was done)
1222 `stack` tinyint(1) default NULL,
1223 `notforloan` tinyint(1) NOT NULL default 0, -- authorized value defining why this item is not for loan (MARC21 952$7)
1224 `damaged` tinyint(1) NOT NULL default 0, -- authorized value defining this item as damaged (MARC21 952$4)
1225 `itemlost` tinyint(1) NOT NULL default 0, -- authorized value defining this item as lost (MARC21 952$1)
1226 `itemlost_on` datetime DEFAULT NULL, -- the date and time an item was last marked as lost, NULL if not lost
1227 `withdrawn` tinyint(1) NOT NULL default 0, -- authorized value defining this item as withdrawn (MARC21 952$0)
1228 `withdrawn_on` datetime DEFAULT NULL, -- the date and time an item was last marked as withdrawn, NULL if not withdrawn
1229 `itemcallnumber` varchar(255) default NULL, -- call number for this item (MARC21 952$o)
1230 `coded_location_qualifier` varchar(10) default NULL, -- coded location qualifier(MARC21 952$f)
1231 `issues` smallint(6) default NULL, -- number of times this item has been checked out/issued
1232 `renewals` smallint(6) default NULL, -- number of times this item has been renewed
1233 `reserves` smallint(6) default NULL, -- number of times this item has been placed on hold/reserved
1234 `restricted` tinyint(1) default NULL, -- authorized value defining use restrictions for this item (MARC21 952$5)
1235 `itemnotes` mediumtext, -- public notes on this item (MARC21 952$x)
1236 `itemnotes_nonpublic` mediumtext default NULL,
1237 `holdingbranch` varchar(10) default NULL, -- foreign key from the branches table for the library that is currently in possession item (MARC21 952$b)
1238 `paidfor` mediumtext,
1239 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- date and time this item was last altered
1240 `location` varchar(80) default NULL, -- authorized value for the shelving location for this item (MARC21 952$c)
1241 `permanent_location` varchar(80) default NULL, -- linked to the CART and PROC temporary locations feature, stores the permanent shelving location
1242 `onloan` date default NULL, -- defines if item is checked out (NULL for not checked out, and checkout date for checked out)
1243 `cn_source` varchar(10) default NULL, -- classification source used on this item (MARC21 952$2)
1244 `cn_sort` varchar(255) default NULL, -- normalized form of the call number (MARC21 952$o) used for sorting
1245 `ccode` varchar(10) default NULL, -- authorized value for the collection code associated with this item (MARC21 952$8)
1246 `materials` text default NULL, -- materials specified (MARC21 952$3)
1247 `uri` varchar(255) default NULL, -- URL for the item (MARC21 952$u)
1248 `itype` varchar(10) default NULL, -- foreign key from the itemtypes table defining the type for this item (MARC21 952$y)
1249 `more_subfields_xml` longtext default NULL, -- additional 952 subfields in XML format
1250 `enumchron` text default NULL, -- serial enumeration/chronology for the item (MARC21 952$h)
1251 `copynumber` varchar(32) default NULL, -- copy number (MARC21 952$t)
1252 `stocknumber` varchar(32) default NULL, -- inventory number (MARC21 952$i)
1253 PRIMARY KEY (`itemnumber`),
1254 UNIQUE KEY `itembarcodeidx` (`barcode`),
1255 KEY `itemstocknumberidx` (`stocknumber`),
1256 KEY `itembinoidx` (`biblioitemnumber`),
1257 KEY `itembibnoidx` (`biblionumber`),
1258 KEY `homebranch` (`homebranch`),
1259 KEY `holdingbranch` (`holdingbranch`),
1260 KEY `itemcallnumber` (`itemcallnumber`),
1261 KEY `items_location` (`location`),
1262 KEY `items_ccode` (`ccode`),
1263 KEY `itype_idx` (`itype`),
1264 CONSTRAINT `items_ibfk_1` FOREIGN KEY (`biblioitemnumber`) REFERENCES `biblioitems` (`biblioitemnumber`) ON DELETE CASCADE ON UPDATE CASCADE,
1265 CONSTRAINT `items_ibfk_2` FOREIGN KEY (`homebranch`) REFERENCES `branches` (`branchcode`) ON UPDATE CASCADE,
1266 CONSTRAINT `items_ibfk_3` FOREIGN KEY (`holdingbranch`) REFERENCES `branches` (`branchcode`) ON UPDATE CASCADE
1267 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1270 -- Table structure for table `itemtypes`
1273 DROP TABLE IF EXISTS `itemtypes`;
1274 CREATE TABLE `itemtypes` ( -- defines the item types
1275 itemtype varchar(10) NOT NULL default '', -- unique key, a code associated with the item type
1276 description mediumtext, -- a plain text explanation of the item type
1277 rentalcharge double(16,4) default NULL, -- the amount charged when this item is checked out/issued
1278 notforloan smallint(6) default NULL, -- 1 if the item is not for loan, 0 if the item is available for loan
1279 imageurl varchar(200) default NULL, -- URL for the item type icon
1280 summary text, -- information from the summary field, may include HTML
1281 checkinmsg VARCHAR(255), -- message that is displayed when an item with the given item type is checked in
1282 checkinmsgtype CHAR(16) DEFAULT 'message' NOT NULL, -- type (CSS class) for the checkinmsg, can be "alert" or "message"
1283 sip_media_type VARCHAR(3) DEFAULT NULL, -- SIP2 protocol media type for this itemtype
1284 PRIMARY KEY (`itemtype`),
1285 UNIQUE KEY `itemtype` (`itemtype`)
1286 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1289 -- Table structure for table `creator_batches`
1292 DROP TABLE IF EXISTS `creator_batches`;
1293 SET @saved_cs_client = @@character_set_client;
1294 SET character_set_client = utf8;
1295 CREATE TABLE `creator_batches` (
1296 `label_id` int(11) NOT NULL AUTO_INCREMENT,
1297 `batch_id` int(10) NOT NULL DEFAULT '1',
1298 `item_number` int(11) DEFAULT NULL,
1299 `borrower_number` int(11) DEFAULT NULL,
1300 `timestamp` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
1301 `branch_code` varchar(10) NOT NULL DEFAULT 'NB',
1302 `creator` char(15) NOT NULL DEFAULT 'Labels',
1303 PRIMARY KEY (`label_id`),
1304 KEY `branch_fk_constraint` (`branch_code`),
1305 KEY `item_fk_constraint` (`item_number`),
1306 KEY `borrower_fk_constraint` (`borrower_number`),
1307 CONSTRAINT `creator_batches_ibfk_1` FOREIGN KEY (`borrower_number`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE,
1308 CONSTRAINT `creator_batches_ibfk_2` FOREIGN KEY (`branch_code`) REFERENCES `branches` (`branchcode`) ON DELETE CASCADE,
1309 CONSTRAINT `creator_batches_ibfk_3` FOREIGN KEY (`item_number`) REFERENCES `items` (`itemnumber`) ON DELETE CASCADE
1310 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1313 -- Table structure for table `creator_images`
1316 DROP TABLE IF EXISTS `creator_images`;
1317 SET @saved_cs_client = @@character_set_client;
1318 SET character_set_client = utf8;
1319 CREATE TABLE `creator_images` (
1320 `image_id` int(4) NOT NULL AUTO_INCREMENT,
1321 `imagefile` mediumblob,
1322 `image_name` char(20) NOT NULL DEFAULT 'DEFAULT',
1323 PRIMARY KEY (`image_id`),
1324 UNIQUE KEY `image_name_index` (`image_name`)
1325 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1328 -- Table structure for table `creator_layouts`
1331 DROP TABLE IF EXISTS `creator_layouts`;
1332 SET @saved_cs_client = @@character_set_client;
1333 SET character_set_client = utf8;
1334 CREATE TABLE `creator_layouts` (
1335 `layout_id` int(4) NOT NULL AUTO_INCREMENT,
1336 `barcode_type` char(100) NOT NULL DEFAULT 'CODE39',
1337 `start_label` int(2) NOT NULL DEFAULT '1',
1338 `printing_type` char(32) NOT NULL DEFAULT 'BAR',
1339 `layout_name` char(20) NOT NULL DEFAULT 'DEFAULT',
1340 `guidebox` int(1) DEFAULT '0',
1341 `font` char(10) CHARACTER SET utf8 COLLATE utf8_unicode_ci NOT NULL DEFAULT 'TR',
1342 `font_size` int(4) NOT NULL DEFAULT '10',
1343 `units` char(20) NOT NULL DEFAULT 'POINT',
1344 `callnum_split` int(1) DEFAULT '0',
1345 `text_justify` char(1) CHARACTER SET utf8 COLLATE utf8_unicode_ci NOT NULL DEFAULT 'L',
1346 `format_string` varchar(210) NOT NULL DEFAULT 'barcode',
1347 `layout_xml` text NOT NULL,
1348 `creator` char(15) NOT NULL DEFAULT 'Labels',
1349 PRIMARY KEY (`layout_id`)
1350 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1353 -- Table structure for table `creator_templates`
1356 DROP TABLE IF EXISTS `creator_templates`;
1357 SET @saved_cs_client = @@character_set_client;
1358 SET character_set_client = utf8;
1359 CREATE TABLE `creator_templates` (
1360 `template_id` int(4) NOT NULL AUTO_INCREMENT,
1361 `profile_id` int(4) DEFAULT NULL,
1362 `template_code` char(100) NOT NULL DEFAULT 'DEFAULT TEMPLATE',
1363 `template_desc` char(100) NOT NULL DEFAULT 'Default description',
1364 `page_width` float NOT NULL DEFAULT '0',
1365 `page_height` float NOT NULL DEFAULT '0',
1366 `label_width` float NOT NULL DEFAULT '0',
1367 `label_height` float NOT NULL DEFAULT '0',
1368 `top_text_margin` float NOT NULL DEFAULT '0',
1369 `left_text_margin` float NOT NULL DEFAULT '0',
1370 `top_margin` float NOT NULL DEFAULT '0',
1371 `left_margin` float NOT NULL DEFAULT '0',
1372 `cols` int(2) NOT NULL DEFAULT '0',
1373 `rows` int(2) NOT NULL DEFAULT '0',
1374 `col_gap` float NOT NULL DEFAULT '0',
1375 `row_gap` float NOT NULL DEFAULT '0',
1376 `units` char(20) NOT NULL DEFAULT 'POINT',
1377 `creator` char(15) NOT NULL DEFAULT 'Labels',
1378 PRIMARY KEY (`template_id`),
1379 KEY `template_profile_fk_constraint` (`profile_id`)
1380 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1383 -- Table structure for table `letter`
1386 DROP TABLE IF EXISTS `letter`;
1387 CREATE TABLE `letter` ( -- table for all notice templates in Koha
1388 `module` varchar(20) NOT NULL default '', -- Koha module that triggers this notice or slip
1389 `code` varchar(20) NOT NULL default '', -- unique identifier for this notice or slip
1390 `branchcode` varchar(10) default NULL, -- the branch this notice or slip is used at (branches.branchcode)
1391 `name` varchar(100) NOT NULL default '', -- plain text name for this notice or slip
1392 `is_html` tinyint(1) default 0, -- does this notice or slip use HTML (1 for yes, 0 for no)
1393 `title` varchar(200) NOT NULL default '', -- subject line of the notice
1394 `content` text, -- body text for the notice or slip
1395 `message_transport_type` varchar(20) NOT NULL DEFAULT 'email', -- transport type for this notice
1396 PRIMARY KEY (`module`,`code`, `branchcode`, `message_transport_type`),
1397 CONSTRAINT `message_transport_type_fk` FOREIGN KEY (`message_transport_type`)
1398 REFERENCES `message_transport_types` (`message_transport_type`) ON DELETE CASCADE ON UPDATE CASCADE
1399 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1402 -- Table structure for table `marc_subfield_structure`
1405 DROP TABLE IF EXISTS `marc_subfield_structure`;
1406 CREATE TABLE `marc_subfield_structure` (
1407 `tagfield` varchar(3) NOT NULL default '',
1408 `tagsubfield` varchar(1) NOT NULL default '' COLLATE utf8_bin,
1409 `liblibrarian` varchar(255) NOT NULL default '',
1410 `libopac` varchar(255) NOT NULL default '',
1411 `repeatable` tinyint(4) NOT NULL default 0,
1412 `mandatory` tinyint(4) NOT NULL default 0,
1413 `kohafield` varchar(40) default NULL,
1414 `tab` tinyint(1) default NULL,
1415 `authorised_value` varchar(20) default NULL,
1416 `authtypecode` varchar(20) default NULL,
1417 `value_builder` varchar(80) default NULL,
1418 `isurl` tinyint(1) default NULL,
1419 `hidden` tinyint(1) default NULL,
1420 `frameworkcode` varchar(4) NOT NULL default '',
1421 `seealso` varchar(1100) default NULL,
1422 `link` varchar(80) default NULL,
1423 `defaultvalue` text default NULL,
1424 `maxlength` int(4) NOT NULL DEFAULT '9999',
1425 PRIMARY KEY (`frameworkcode`,`tagfield`,`tagsubfield`),
1426 KEY `kohafield_2` (`kohafield`),
1427 KEY `tab` (`frameworkcode`,`tab`),
1428 KEY `kohafield` (`frameworkcode`,`kohafield`)
1429 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1432 -- Table structure for table `marc_tag_structure`
1435 DROP TABLE IF EXISTS `marc_tag_structure`;
1436 CREATE TABLE `marc_tag_structure` (
1437 `tagfield` varchar(3) NOT NULL default '',
1438 `liblibrarian` varchar(255) NOT NULL default '',
1439 `libopac` varchar(255) NOT NULL default '',
1440 `repeatable` tinyint(4) NOT NULL default 0,
1441 `mandatory` tinyint(4) NOT NULL default 0,
1442 `authorised_value` varchar(10) default NULL,
1443 `frameworkcode` varchar(4) NOT NULL default '',
1444 PRIMARY KEY (`frameworkcode`,`tagfield`)
1445 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1448 -- Table structure for table `marc_matchers`
1451 DROP TABLE IF EXISTS `marc_matchers`;
1452 CREATE TABLE `marc_matchers` (
1453 `matcher_id` int(11) NOT NULL auto_increment,
1454 `code` varchar(10) NOT NULL default '',
1455 `description` varchar(255) NOT NULL default '',
1456 `record_type` varchar(10) NOT NULL default 'biblio',
1457 `threshold` int(11) NOT NULL default 0,
1458 PRIMARY KEY (`matcher_id`),
1459 KEY `code` (`code`),
1460 KEY `record_type` (`record_type`)
1461 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1464 -- Table structure for table `matchpoints`
1466 DROP TABLE IF EXISTS `matchpoints`;
1467 CREATE TABLE `matchpoints` (
1468 `matcher_id` int(11) NOT NULL,
1469 `matchpoint_id` int(11) NOT NULL auto_increment,
1470 `search_index` varchar(30) NOT NULL default '',
1471 `score` int(11) NOT NULL default 0,
1472 PRIMARY KEY (`matchpoint_id`),
1473 CONSTRAINT `matchpoints_ifbk_1` FOREIGN KEY (`matcher_id`)
1474 REFERENCES `marc_matchers` (`matcher_id`) ON DELETE CASCADE ON UPDATE CASCADE
1475 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1479 -- Table structure for table `matchpoint_components`
1481 DROP TABLE IF EXISTS `matchpoint_components`;
1482 CREATE TABLE `matchpoint_components` (
1483 `matchpoint_id` int(11) NOT NULL,
1484 `matchpoint_component_id` int(11) NOT NULL auto_increment,
1485 sequence int(11) NOT NULL default 0,
1486 tag varchar(3) NOT NULL default '',
1487 subfields varchar(40) NOT NULL default '',
1488 offset int(4) NOT NULL default 0,
1489 length int(4) NOT NULL default 0,
1490 PRIMARY KEY (`matchpoint_component_id`),
1491 KEY `by_sequence` (`matchpoint_id`, `sequence`),
1492 CONSTRAINT `matchpoint_components_ifbk_1` FOREIGN KEY (`matchpoint_id`)
1493 REFERENCES `matchpoints` (`matchpoint_id`) ON DELETE CASCADE ON UPDATE CASCADE
1494 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1497 -- Table structure for table `matcher_component_norms`
1499 DROP TABLE IF EXISTS `matchpoint_component_norms`;
1500 CREATE TABLE `matchpoint_component_norms` (
1501 `matchpoint_component_id` int(11) NOT NULL,
1502 `sequence` int(11) NOT NULL default 0,
1503 `norm_routine` varchar(50) NOT NULL default '',
1504 KEY `matchpoint_component_norms` (`matchpoint_component_id`, `sequence`),
1505 CONSTRAINT `matchpoint_component_norms_ifbk_1` FOREIGN KEY (`matchpoint_component_id`)
1506 REFERENCES `matchpoint_components` (`matchpoint_component_id`) ON DELETE CASCADE ON UPDATE CASCADE
1507 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1510 -- Table structure for table `matcher_matchpoints`
1512 DROP TABLE IF EXISTS `matcher_matchpoints`;
1513 CREATE TABLE `matcher_matchpoints` (
1514 `matcher_id` int(11) NOT NULL,
1515 `matchpoint_id` int(11) NOT NULL,
1516 CONSTRAINT `matcher_matchpoints_ifbk_1` FOREIGN KEY (`matcher_id`)
1517 REFERENCES `marc_matchers` (`matcher_id`) ON DELETE CASCADE ON UPDATE CASCADE,
1518 CONSTRAINT `matcher_matchpoints_ifbk_2` FOREIGN KEY (`matchpoint_id`)
1519 REFERENCES `matchpoints` (`matchpoint_id`) ON DELETE CASCADE ON UPDATE CASCADE
1520 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1523 -- Table structure for table `matchchecks`
1525 DROP TABLE IF EXISTS `matchchecks`;
1526 CREATE TABLE `matchchecks` (
1527 `matcher_id` int(11) NOT NULL,
1528 `matchcheck_id` int(11) NOT NULL auto_increment,
1529 `source_matchpoint_id` int(11) NOT NULL,
1530 `target_matchpoint_id` int(11) NOT NULL,
1531 PRIMARY KEY (`matchcheck_id`),
1532 CONSTRAINT `matcher_matchchecks_ifbk_1` FOREIGN KEY (`matcher_id`)
1533 REFERENCES `marc_matchers` (`matcher_id`) ON DELETE CASCADE ON UPDATE CASCADE,
1534 CONSTRAINT `matcher_matchchecks_ifbk_2` FOREIGN KEY (`source_matchpoint_id`)
1535 REFERENCES `matchpoints` (`matchpoint_id`) ON DELETE CASCADE ON UPDATE CASCADE,
1536 CONSTRAINT `matcher_matchchecks_ifbk_3` FOREIGN KEY (`target_matchpoint_id`)
1537 REFERENCES `matchpoints` (`matchpoint_id`) ON DELETE CASCADE ON UPDATE CASCADE
1538 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1541 -- Table structure for table `need_merge_authorities`
1544 DROP TABLE IF EXISTS `need_merge_authorities`;
1545 CREATE TABLE `need_merge_authorities` ( -- keeping track of authority records still to be merged by merge_authority cron job (used only if pref dontmerge is ON)
1546 `id` int NOT NULL auto_increment PRIMARY KEY, -- unique id
1547 `authid` bigint NOT NULL, -- reference to authority record
1548 `done` tinyint DEFAULT 0 -- indication whether merge has been executed (0=not done, 1= done, 2= in progress)
1549 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1552 -- Table structure for table `notifys`
1555 DROP TABLE IF EXISTS `notifys`;
1556 CREATE TABLE `notifys` (
1557 `notify_id` int(11) NOT NULL default 0,
1558 `borrowernumber` int(11) NOT NULL default 0,
1559 `itemnumber` int(11) NOT NULL default 0,
1560 `notify_date` date default NULL,
1561 `notify_send_date` date default NULL,
1562 `notify_level` int(1) NOT NULL default 0,
1563 `method` varchar(20) NOT NULL default ''
1564 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1567 -- Table structure for table `oai_sets`
1570 DROP TABLE IF EXISTS `oai_sets`;
1571 CREATE TABLE `oai_sets` (
1572 `id` int(11) NOT NULL auto_increment,
1573 `spec` varchar(80) NOT NULL UNIQUE,
1574 `name` varchar(80) NOT NULL,
1576 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1579 -- Table structure for table `oai_sets_descriptions`
1582 DROP TABLE IF EXISTS `oai_sets_descriptions`;
1583 CREATE TABLE `oai_sets_descriptions` (
1584 `set_id` int(11) NOT NULL,
1585 `description` varchar(255) NOT NULL,
1586 CONSTRAINT `oai_sets_descriptions_ibfk_1` FOREIGN KEY (`set_id`) REFERENCES `oai_sets` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
1587 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1590 -- Table structure for table `oai_sets_mappings`
1593 DROP TABLE IF EXISTS `oai_sets_mappings`;
1594 CREATE TABLE `oai_sets_mappings` (
1595 `set_id` int(11) NOT NULL,
1596 `marcfield` char(3) NOT NULL,
1597 `marcsubfield` char(1) NOT NULL,
1598 `operator` varchar(8) NOT NULL default 'equal',
1599 `marcvalue` varchar(80) NOT NULL,
1600 CONSTRAINT `oai_sets_mappings_ibfk_1` FOREIGN KEY (`set_id`) REFERENCES `oai_sets` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
1601 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1604 -- Table structure for table `oai_sets_biblios`
1607 DROP TABLE IF EXISTS `oai_sets_biblios`;
1608 CREATE TABLE `oai_sets_biblios` (
1609 `biblionumber` int(11) NOT NULL,
1610 `set_id` int(11) NOT NULL,
1611 PRIMARY KEY (`biblionumber`, `set_id`),
1612 CONSTRAINT `oai_sets_biblios_ibfk_1` FOREIGN KEY (`biblionumber`) REFERENCES `biblio` (`biblionumber`) ON DELETE CASCADE ON UPDATE CASCADE,
1613 CONSTRAINT `oai_sets_biblios_ibfk_2` FOREIGN KEY (`set_id`) REFERENCES `oai_sets` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
1614 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1617 -- Table structure for table `old_issues`
1620 DROP TABLE IF EXISTS `old_issues`;
1621 CREATE TABLE `old_issues` ( -- lists items that were checked out and have been returned
1622 `issue_id` int(11) NOT NULL, -- primary key for issues table
1623 `borrowernumber` int(11) default NULL, -- foreign key, linking this to the borrowers table for the patron this item was checked out to
1624 `itemnumber` int(11) default NULL, -- foreign key, linking this to the items table for the item that was checked out
1625 `date_due` datetime default NULL, -- date the item is due (yyyy-mm-dd)
1626 `branchcode` varchar(10) default NULL, -- foreign key, linking to the branches table for the location the item was checked out
1627 `returndate` datetime default NULL, -- date the item was returned
1628 `lastreneweddate` datetime default NULL, -- date the item was last renewed
1629 `return` varchar(4) default NULL,
1630 `renewals` tinyint(4) default NULL, -- lists the number of times the item was renewed
1631 `auto_renew` BOOLEAN default FALSE, -- automatic renewal
1632 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- the date and time this record was last touched
1633 `issuedate` datetime default NULL, -- date the item was checked out or issued
1634 `onsite_checkout` int(1) NOT NULL default 0, -- in house use flag
1635 PRIMARY KEY (`issue_id`),
1636 KEY `old_issuesborridx` (`borrowernumber`),
1637 KEY `old_issuesitemidx` (`itemnumber`),
1638 KEY `branchcode_idx` (`branchcode`),
1639 KEY `old_bordate` (`borrowernumber`,`timestamp`),
1640 CONSTRAINT `old_issues_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`)
1641 ON DELETE SET NULL ON UPDATE SET NULL,
1642 CONSTRAINT `old_issues_ibfk_2` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`)
1643 ON DELETE SET NULL ON UPDATE SET NULL
1644 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1647 -- Table structure for table `old_reserves`
1649 DROP TABLE IF EXISTS `old_reserves`;
1650 CREATE TABLE `old_reserves` ( -- this table holds all holds/reserves that have been completed (either filled or cancelled)
1651 `reserve_id` int(11) NOT NULL, -- primary key
1652 `borrowernumber` int(11) default NULL, -- foreign key from the borrowers table defining which patron this hold is for
1653 `reservedate` date default NULL, -- the date the hold was places
1654 `biblionumber` int(11) default NULL, -- foreign key from the biblio table defining which bib record this hold is on
1655 `constrainttype` varchar(1) default NULL,
1656 `branchcode` varchar(10) default NULL, -- foreign key from the branches table defining which branch the patron wishes to pick this hold up at
1657 `notificationdate` date default NULL, -- currently unused
1658 `reminderdate` date default NULL, -- currently unused
1659 `cancellationdate` date default NULL, -- the date this hold was cancelled
1660 `reservenotes` mediumtext, -- notes related to this hold
1661 `priority` smallint(6) default NULL, -- where in the queue the patron sits
1662 `found` varchar(1) default NULL, -- a one letter code defining what the status is of the hold is after it has been confirmed
1663 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- the date and time this hold was last updated
1664 `itemnumber` int(11) default NULL, -- foreign key from the items table defining the specific item the patron has placed on hold or the item this hold was filled with
1665 `waitingdate` date default NULL, -- the date the item was marked as waiting for the patron at the library
1666 `expirationdate` DATE DEFAULT NULL, -- the date the hold expires (usually the date entered by the patron to say they don't need the hold after a certain date)
1667 `lowestPriority` tinyint(1) NOT NULL, -- has this hold been pinned to the lowest priority in the holds queue (1 for yes, 0 for no)
1668 `suspend` BOOLEAN NOT NULL DEFAULT 0, -- in this hold suspended (1 for yes, 0 for no)
1669 `suspend_until` DATETIME NULL DEFAULT NULL, -- the date this hold is suspended until (NULL for infinitely)
1670 PRIMARY KEY (`reserve_id`),
1671 KEY `old_reserves_borrowernumber` (`borrowernumber`),
1672 KEY `old_reserves_biblionumber` (`biblionumber`),
1673 KEY `old_reserves_itemnumber` (`itemnumber`),
1674 KEY `old_reserves_branchcode` (`branchcode`),
1675 CONSTRAINT `old_reserves_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`)
1676 ON DELETE SET NULL ON UPDATE SET NULL,
1677 CONSTRAINT `old_reserves_ibfk_2` FOREIGN KEY (`biblionumber`) REFERENCES `biblio` (`biblionumber`)
1678 ON DELETE SET NULL ON UPDATE SET NULL,
1679 CONSTRAINT `old_reserves_ibfk_3` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`)
1680 ON DELETE SET NULL ON UPDATE SET NULL
1681 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1684 -- Table structure for table `opac_news`
1687 DROP TABLE IF EXISTS `opac_news`;
1688 CREATE TABLE `opac_news` ( -- data from the news tool
1689 `idnew` int(10) unsigned NOT NULL auto_increment, -- unique identifier for the news article
1690 `branchcode` varchar(10) default NULL, -- branch code users to create branch specific news, NULL is every branch.
1691 `title` varchar(250) NOT NULL default '', -- title of the news article
1692 `new` text NOT NULL, -- the body of your news article
1693 `lang` varchar(25) NOT NULL default '', -- location for the article (koha is the staff client, slip is the circulation receipt and language codes are for the opac)
1694 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP, -- pulibcation date and time
1695 `expirationdate` date default NULL, -- date the article is set to expire or no longer be visible
1696 `number` int(11) default NULL, -- the order in which this article appears in that specific location
1697 PRIMARY KEY (`idnew`),
1698 CONSTRAINT opac_news_branchcode_ibfk FOREIGN KEY (branchcode) REFERENCES branches (branchcode)
1699 ON DELETE CASCADE ON UPDATE CASCADE
1700 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1703 -- Table structure for table `overduerules`
1706 DROP TABLE IF EXISTS `overduerules`;
1707 CREATE TABLE `overduerules` ( -- overdue notice status and triggers
1708 `branchcode` varchar(10) NOT NULL default '', -- foreign key from the branches table to define which branch this rule is for (if blank it's all libraries)
1709 `categorycode` varchar(10) NOT NULL default '', -- foreign key from the categories table to define which patron category this rule is for
1710 `delay1` int(4) default NULL, -- number of days after the item is overdue that the first notice is sent
1711 `letter1` varchar(20) default NULL, -- foreign key from the letter table to define which notice should be sent as the first notice
1712 `debarred1` varchar(1) default 0, -- is the patron restricted when the first notice is sent (1 for yes, 0 for no)
1713 `delay2` int(4) default NULL, -- number of days after the item is overdue that the second notice is sent
1714 `debarred2` varchar(1) default 0, -- is the patron restricted when the second notice is sent (1 for yes, 0 for no)
1715 `letter2` varchar(20) default NULL, -- foreign key from the letter table to define which notice should be sent as the second notice
1716 `delay3` int(4) default NULL, -- number of days after the item is overdue that the third notice is sent
1717 `letter3` varchar(20) default NULL, -- foreign key from the letter table to define which notice should be sent as the third notice
1718 `debarred3` int(1) default 0, -- is the patron restricted when the third notice is sent (1 for yes, 0 for no)
1719 PRIMARY KEY (`branchcode`,`categorycode`)
1720 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1723 -- Table structure for table `patronimage`
1726 DROP TABLE IF EXISTS `patronimage`;
1727 CREATE TABLE `patronimage` ( -- information related to patron images
1728 `borrowernumber` int(11) NOT NULL, -- the borrowernumber of the patron this image is attached to (borrowers.borrowernumber)
1729 `mimetype` varchar(15) NOT NULL, -- the format of the image (png, jpg, etc)
1730 `imagefile` mediumblob NOT NULL, -- the image
1731 PRIMARY KEY (`borrowernumber`),
1732 CONSTRAINT `patronimage_fk1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE
1733 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1735 -- Table structure for table `pending_offline_operations`
1737 -- this table is MyISAM, InnoDB tables are growing only and this table is filled/emptied/filled/emptied...
1738 -- so MyISAM is better in this case
1740 DROP TABLE IF EXISTS `pending_offline_operations`;
1741 CREATE TABLE pending_offline_operations (
1742 operationid int(11) NOT NULL AUTO_INCREMENT,
1743 userid varchar(30) NOT NULL,
1744 branchcode varchar(10) NOT NULL,
1745 `timestamp` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
1746 `action` varchar(10) NOT NULL,
1747 barcode varchar(20) DEFAULT NULL,
1748 cardnumber varchar(16) DEFAULT NULL,
1749 amount decimal(28,6) DEFAULT NULL,
1750 PRIMARY KEY (operationid)
1751 ) ENGINE=MyISAM DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1755 -- Table structure for table `printers`
1758 DROP TABLE IF EXISTS `printers`;
1759 CREATE TABLE `printers` (
1760 `printername` varchar(40) NOT NULL default '',
1761 `printqueue` varchar(20) default NULL,
1762 `printtype` varchar(20) default NULL,
1763 PRIMARY KEY (`printername`)
1764 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1767 -- Table structure for table `printers_profile`
1770 DROP TABLE IF EXISTS `printers_profile`;
1771 CREATE TABLE `printers_profile` (
1772 `profile_id` int(4) NOT NULL auto_increment,
1773 `printer_name` varchar(40) NOT NULL default 'Default Printer',
1774 `template_id` int(4) NOT NULL default '0',
1775 `paper_bin` varchar(20) NOT NULL default 'Bypass',
1776 `offset_horz` float NOT NULL default '0',
1777 `offset_vert` float NOT NULL default '0',
1778 `creep_horz` float NOT NULL default '0',
1779 `creep_vert` float NOT NULL default '0',
1780 `units` char(20) NOT NULL default 'POINT',
1781 `creator` char(15) NOT NULL DEFAULT 'Labels',
1782 PRIMARY KEY (`profile_id`),
1783 UNIQUE KEY `printername` (`printer_name`,`template_id`,`paper_bin`,`creator`)
1784 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1787 -- Table structure for table `repeatable_holidays`
1790 DROP TABLE IF EXISTS `repeatable_holidays`;
1791 CREATE TABLE `repeatable_holidays` ( -- information for the days the library is closed
1792 `id` int(11) NOT NULL auto_increment, -- unique identifier assigned by Koha
1793 `branchcode` varchar(10) NOT NULL default '', -- foreign key from the branches table, defines which branch this closing is for
1794 `weekday` smallint(6) default NULL, -- day of the week (0=Sunday, 1=Monday, etc) this closing is repeated on
1795 `day` smallint(6) default NULL, -- day of the month this closing is on
1796 `month` smallint(6) default NULL, -- month this closing is in
1797 `title` varchar(50) NOT NULL default '', -- title of this closing
1798 `description` text NOT NULL, -- description for this closing
1800 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1803 -- Table structure for table `reports_dictionary`
1806 DROP TABLE IF EXISTS `reports_dictionary`;
1807 CREATE TABLE reports_dictionary ( -- definitions (or snippets of SQL) stored for use in reports
1808 `id` int(11) NOT NULL auto_increment, -- unique identifier assigned by Koha
1809 `name` varchar(255) default NULL, -- name for this definition
1810 `description` text, -- description for this definition
1811 `date_created` datetime default NULL, -- date and time this definition was created
1812 `date_modified` datetime default NULL, -- date and time this definition was last modified
1813 `saved_sql` text, -- SQL snippet for us in reports
1814 report_area varchar(6) DEFAULT NULL, -- Koha module this definition is for Circulation, Catalog, Patrons, Acquistions, Accounts)
1816 KEY dictionary_area_idx (report_area)
1817 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1820 -- Table structure for table `reserveconstraints`
1823 DROP TABLE IF EXISTS `reserveconstraints`;
1824 CREATE TABLE `reserveconstraints` (
1825 `borrowernumber` int(11) NOT NULL default 0,
1826 `reservedate` date default NULL,
1827 `biblionumber` int(11) NOT NULL default 0,
1828 `biblioitemnumber` int(11) default NULL,
1829 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP
1830 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1833 -- Table structure for table `reserves`
1836 DROP TABLE IF EXISTS `reserves`;
1837 CREATE TABLE `reserves` ( -- information related to holds/reserves in Koha
1838 `reserve_id` int(11) NOT NULL auto_increment, -- primary key
1839 `borrowernumber` int(11) NOT NULL default 0, -- foreign key from the borrowers table defining which patron this hold is for
1840 `reservedate` date default NULL, -- the date the hold was places
1841 `biblionumber` int(11) NOT NULL default 0, -- foreign key from the biblio table defining which bib record this hold is on
1842 `constrainttype` varchar(1) default NULL,
1843 `branchcode` varchar(10) default NULL, -- foreign key from the branches table defining which branch the patron wishes to pick this hold up at
1844 `notificationdate` date default NULL, -- currently unused
1845 `reminderdate` date default NULL, -- currently unused
1846 `cancellationdate` date default NULL, -- the date this hold was cancelled
1847 `reservenotes` mediumtext, -- notes related to this hold
1848 `priority` smallint(6) default NULL, -- where in the queue the patron sits
1849 `found` varchar(1) default NULL, -- a one letter code defining what the status is of the hold is after it has been confirmed
1850 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- the date and time this hold was last updated
1851 `itemnumber` int(11) default NULL, -- foreign key from the items table defining the specific item the patron has placed on hold or the item this hold was filled with
1852 `waitingdate` date default NULL, -- the date the item was marked as waiting for the patron at the library
1853 `expirationdate` DATE DEFAULT NULL, -- the date the hold expires (usually the date entered by the patron to say they don't need the hold after a certain date)
1854 `lowestPriority` tinyint(1) NOT NULL,
1855 `suspend` BOOLEAN NOT NULL DEFAULT 0,
1856 `suspend_until` DATETIME NULL DEFAULT NULL,
1857 PRIMARY KEY (`reserve_id`),
1858 KEY priorityfoundidx (priority,found),
1859 KEY `borrowernumber` (`borrowernumber`),
1860 KEY `biblionumber` (`biblionumber`),
1861 KEY `itemnumber` (`itemnumber`),
1862 KEY `branchcode` (`branchcode`),
1863 CONSTRAINT `reserves_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE,
1864 CONSTRAINT `reserves_ibfk_2` FOREIGN KEY (`biblionumber`) REFERENCES `biblio` (`biblionumber`) ON DELETE CASCADE ON UPDATE CASCADE,
1865 CONSTRAINT `reserves_ibfk_3` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`) ON DELETE CASCADE ON UPDATE CASCADE,
1866 CONSTRAINT `reserves_ibfk_4` FOREIGN KEY (`branchcode`) REFERENCES `branches` (`branchcode`) ON DELETE CASCADE ON UPDATE CASCADE
1867 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1870 -- Table structure for table `reviews`
1873 DROP TABLE IF EXISTS `reviews`;
1874 CREATE TABLE `reviews` ( -- patron opac comments
1875 `reviewid` int(11) NOT NULL auto_increment, -- unique identifier for this comment
1876 `borrowernumber` int(11) default NULL, -- foreign key from the borrowers table defining which patron left this comment
1877 `biblionumber` int(11) default NULL, -- foreign key from the biblio table defining which bibliographic record this comment is for
1878 `review` text, -- the body of the comment
1879 `approved` tinyint(4) default NULL, -- whether this comment has been approved by a librarian (1 for yes, 0 for no)
1880 `datereviewed` datetime default NULL, -- the date the comment was left
1881 PRIMARY KEY (`reviewid`),
1882 CONSTRAINT `reviews_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE SET NULL ON UPDATE CASCADE,
1883 CONSTRAINT `reviews_ibfk_2` FOREIGN KEY (`biblionumber`) REFERENCES `biblio` (`biblionumber`) ON DELETE CASCADE ON UPDATE CASCADE
1884 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1887 -- Table structure for table `saved_sql`
1890 DROP TABLE IF EXISTS `saved_sql`;
1891 CREATE TABLE saved_sql ( -- saved sql reports
1892 `id` int(11) NOT NULL auto_increment, -- unique id and primary key assigned by Koha
1893 `borrowernumber` int(11) default NULL, -- the staff member who created this report (borrowers.borrowernumber)
1894 `date_created` datetime default NULL, -- the date this report was created
1895 `last_modified` datetime default NULL, -- the date this report was last edited
1896 `savedsql` text, -- the SQL for this report
1897 `last_run` datetime default NULL,
1898 `report_name` varchar(255) NOT NULL default '', -- the name of this report
1899 `type` varchar(255) default NULL, -- always 1 for tabular
1900 `notes` text, -- the notes or description given to this report
1901 `cache_expiry` int NOT NULL default 300,
1902 `public` boolean NOT NULL default FALSE,
1903 report_area varchar(6) default NULL,
1904 report_group varchar(80) default NULL,
1905 report_subgroup varchar(80) default NULL,
1907 KEY sql_area_group_idx (report_group, report_subgroup),
1908 KEY boridx (`borrowernumber`)
1909 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1913 -- Table structure for `saved_reports`
1916 DROP TABLE IF EXISTS `saved_reports`;
1917 CREATE TABLE saved_reports (
1918 `id` int(11) NOT NULL auto_increment,
1919 `report_id` int(11) default NULL,
1921 `date_run` datetime default NULL,
1923 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1927 -- Table structure for table `search_history`
1930 DROP TABLE IF EXISTS `search_history`;
1931 CREATE TABLE IF NOT EXISTS `search_history` ( -- patron's opac search history
1932 `id` int(11) NOT NULL auto_increment, -- search history id
1933 `userid` int(11) NOT NULL, -- the patron who performed the search (borrowers.borrowernumber)
1934 `sessionid` varchar(32) NOT NULL, -- a system generated session id
1935 `query_desc` varchar(255) NOT NULL, -- the search that was performed
1936 `query_cgi` text NOT NULL, -- the string to append to the search url to rerun the search
1937 `type` varchar(16) NOT NULL DEFAULT 'biblio', -- search type, must be 'biblio' or 'authority'
1938 `total` int(11) NOT NULL, -- the total of results found
1939 `time` timestamp NOT NULL default CURRENT_TIMESTAMP, -- the date and time the search was run
1940 KEY `userid` (`userid`),
1941 KEY `sessionid` (`sessionid`),
1943 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci COMMENT='Opac search history results';
1947 -- Table structure for table `serial`
1950 DROP TABLE IF EXISTS `serial`;
1951 CREATE TABLE `serial` ( -- issues related to subscriptions
1952 `serialid` int(11) NOT NULL auto_increment, -- unique key for the issue
1953 `biblionumber` varchar(100) NOT NULL default '', -- foreign key for the biblio.biblionumber that this issue is attached to
1954 `subscriptionid` varchar(100) NOT NULL default '', -- foreign key to the subscription.subscriptionid that this issue is part of
1955 `serialseq` varchar(100) NOT NULL default '', -- issue information (volume, number, etc)
1956 `status` tinyint(4) NOT NULL default 0, -- status code for this issue (see manual for full descriptions)
1957 `planneddate` date default NULL, -- date expected
1958 `notes` text, -- notes
1959 `publisheddate` date default NULL, -- date published
1960 `claimdate` date default NULL, -- date claimed
1961 claims_count int(11) default 0, -- number of claims made related to this issue
1962 `routingnotes` text, -- notes from the routing list
1963 PRIMARY KEY (`serialid`)
1964 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1967 -- Table structure for table `sessions`
1970 DROP TABLE IF EXISTS sessions;
1971 CREATE TABLE sessions (
1972 `id` varchar(32) NOT NULL,
1973 `a_session` mediumtext NOT NULL,
1975 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1978 -- Table structure for table `special_holidays`
1981 DROP TABLE IF EXISTS `special_holidays`;
1982 CREATE TABLE `special_holidays` ( -- non repeatable holidays/library closings
1983 `id` int(11) NOT NULL auto_increment, -- unique identifier assigned by Koha
1984 `branchcode` varchar(10) NOT NULL default '', -- foreign key from the branches table, defines which branch this closing is for
1985 `day` smallint(6) NOT NULL default 0, -- day of the month this closing is on
1986 `month` smallint(6) NOT NULL default 0, -- month this closing is in
1987 `year` smallint(6) NOT NULL default 0, -- year this closing is in
1988 `isexception` smallint(1) NOT NULL default 1, -- is this a holiday exception to a repeatable holiday (1 for yes, 0 for no)
1989 `title` varchar(50) NOT NULL default '', -- title for this closing
1990 `description` text NOT NULL, -- description of this closing
1992 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1995 -- Table structure for table `statistics`
1998 DROP TABLE IF EXISTS `statistics`;
1999 CREATE TABLE `statistics` ( -- information related to transactions (circulation and fines) in Koha
2000 `datetime` datetime default NULL, -- date and time of the transaction
2001 `branch` varchar(10) default NULL, -- foreign key, branch where the transaction occurred
2002 `proccode` varchar(4) default NULL, -- type of procedure used when making payments (does not appear in the code)
2003 `value` double(16,4) default NULL, -- monetary value associated with the transaction
2004 `type` varchar(16) default NULL, -- transaction type (locause, issue, return, renew, writeoff, payment, Credit*)
2005 `other` mediumtext, -- used by SIP
2006 `usercode` varchar(10) default NULL, -- unused in Koha
2007 `itemnumber` int(11) default NULL, -- foreign key from the items table, links transaction to a specific item
2008 `itemtype` varchar(10) default NULL, -- foreign key from the itemtypes table, links transaction to a specific item type
2009 `borrowernumber` int(11) default NULL, -- foreign key from the borrowers table, links transaction to a specific borrower
2010 `associatedborrower` int(11) default NULL, -- unused in Koha
2011 `ccode` varchar(10) default NULL, -- foreign key from the items table, links transaction to a specific collection code
2012 KEY `timeidx` (`datetime`),
2013 KEY `branch_idx` (`branch`),
2014 KEY `proccode_idx` (`proccode`),
2015 KEY `type_idx` (`type`),
2016 KEY `usercode_idx` (`usercode`),
2017 KEY `itemnumber_idx` (`itemnumber`),
2018 KEY `itemtype_idx` (`itemtype`),
2019 KEY `borrowernumber_idx` (`borrowernumber`),
2020 KEY `associatedborrower_idx` (`associatedborrower`),
2021 KEY `ccode_idx` (`ccode`)
2022 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2025 -- Table structure for table `stopwords`
2028 DROP TABLE IF EXISTS `stopwords`;
2029 CREATE TABLE `stopwords` (
2030 `word` varchar(255) default NULL
2031 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2034 -- Table structure for table subscription_frequencies
2037 DROP TABLE IF EXISTS subscription_frequencies;
2038 CREATE TABLE subscription_frequencies (
2039 id INTEGER NOT NULL AUTO_INCREMENT,
2040 description TEXT NOT NULL,
2041 displayorder INT DEFAULT NULL,
2042 unit ENUM('day','week','month','year') DEFAULT NULL,
2043 unitsperissue INTEGER NOT NULL DEFAULT '1',
2044 issuesperunit INTEGER NOT NULL DEFAULT '1',
2046 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2049 -- Table structure for table subscription_numberpatterns
2052 DROP TABLE IF EXISTS subscription_numberpatterns;
2053 CREATE TABLE subscription_numberpatterns (
2054 id INTEGER NOT NULL AUTO_INCREMENT,
2055 label VARCHAR(255) NOT NULL,
2056 displayorder INTEGER DEFAULT NULL,
2057 description TEXT NOT NULL,
2058 numberingmethod VARCHAR(255) NOT NULL,
2059 label1 VARCHAR(255) DEFAULT NULL,
2060 add1 INTEGER DEFAULT NULL,
2061 every1 INTEGER DEFAULT NULL,
2062 whenmorethan1 INTEGER DEFAULT NULL,
2063 setto1 INTEGER DEFAULT NULL,
2064 numbering1 VARCHAR(255) DEFAULT NULL,
2065 label2 VARCHAR(255) DEFAULT NULL,
2066 add2 INTEGER DEFAULT NULL,
2067 every2 INTEGER DEFAULT NULL,
2068 whenmorethan2 INTEGER DEFAULT NULL,
2069 setto2 INTEGER DEFAULT NULL,
2070 numbering2 VARCHAR(255) DEFAULT NULL,
2071 label3 VARCHAR(255) DEFAULT NULL,
2072 add3 INTEGER DEFAULT NULL,
2073 every3 INTEGER DEFAULT NULL,
2074 whenmorethan3 INTEGER DEFAULT NULL,
2075 setto3 INTEGER DEFAULT NULL,
2076 numbering3 VARCHAR(255) DEFAULT NULL,
2078 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2081 -- Table structure for table `subscription`
2084 DROP TABLE IF EXISTS `subscription`;
2085 CREATE TABLE `subscription` ( -- information related to the subscription
2086 `biblionumber` int(11) NOT NULL default 0, -- foreign key for biblio.biblionumber that this subscription is attached to
2087 `subscriptionid` int(11) NOT NULL auto_increment, -- unique key for this subscription
2088 `librarian` varchar(100) default '', -- the librarian's username from borrowers.userid
2089 `startdate` date default NULL, -- start date for this subscription
2090 `aqbooksellerid` int(11) default 0, -- foreign key for aqbooksellers.id to link to the vendor
2091 `cost` int(11) default 0,
2092 `aqbudgetid` int(11) default 0,
2093 `weeklength` int(11) default 0, -- subscription length in weeks (will not be filled in if monthlength or numberlength is set)
2094 `monthlength` int(11) default 0, -- subscription length in weeks (will not be filled in if weeklength or numberlength is set)
2095 `numberlength` int(11) default 0, -- subscription length in weeks (will not be filled in if monthlength or weeklength is set)
2096 `periodicity` integer default null, -- frequency type links to subscription_frequencies.id
2097 countissuesperunit INTEGER NOT NULL DEFAULT 1,
2098 `notes` mediumtext, -- notes
2099 `status` varchar(100) NOT NULL default '', -- status of this subscription
2100 `lastvalue1` int(11) default NULL,
2101 `innerloop1` int(11) default 0,
2102 `lastvalue2` int(11) default NULL,
2103 `innerloop2` int(11) default 0,
2104 `lastvalue3` int(11) default NULL,
2105 `innerloop3` int(11) default 0,
2106 `firstacquidate` date default NULL, -- first issue received date
2107 `manualhistory` tinyint(1) NOT NULL default 0, -- yes or no to managing the history manually
2108 `irregularity` text, -- any irregularities in the subscription
2109 skip_serialseq BOOLEAN NOT NULL DEFAULT 0,
2110 `letter` varchar(20) default NULL,
2111 `numberpattern` integer default null, -- the numbering pattern used links to subscription_numberpatterns.id
2112 locale VARCHAR(80) DEFAULT NULL, -- for foreign language subscriptions to display months, seasons, etc correctly
2113 `distributedto` text,
2114 `internalnotes` longtext,
2115 `callnumber` text, -- default call number
2116 `location` varchar(80) NULL default '', -- default shelving location (items.location)
2117 `branchcode` varchar(10) NOT NULL default '', -- default branches (items.homebranch)
2118 `lastbranch` varchar(10),
2119 `serialsadditems` tinyint(1) NOT NULL default '0', -- does receiving this serial create an item record
2120 `staffdisplaycount` VARCHAR(10) NULL, -- how many issues to show to the staff
2121 `opacdisplaycount` VARCHAR(10) NULL, -- how many issues to show to the public
2122 `graceperiod` int(11) NOT NULL default '0', -- grace period in days
2123 `enddate` date default NULL, -- subscription end date
2124 `closed` INT(1) NOT NULL DEFAULT 0, -- yes / no if the subscription is closed
2125 `reneweddate` date default NULL, -- date of last renewal for the subscription
2126 PRIMARY KEY (`subscriptionid`),
2127 CONSTRAINT subscription_ibfk_1 FOREIGN KEY (periodicity) REFERENCES subscription_frequencies (id) ON DELETE SET NULL ON UPDATE CASCADE,
2128 CONSTRAINT subscription_ibfk_2 FOREIGN KEY (numberpattern) REFERENCES subscription_numberpatterns (id) ON DELETE SET NULL ON UPDATE CASCADE
2129 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2132 -- Table structure for table `subscriptionhistory`
2135 DROP TABLE IF EXISTS `subscriptionhistory`;
2136 CREATE TABLE `subscriptionhistory` (
2137 `biblionumber` int(11) NOT NULL default 0,
2138 `subscriptionid` int(11) NOT NULL default 0,
2139 `histstartdate` date default NULL,
2140 `histenddate` date default NULL,
2141 `missinglist` longtext NOT NULL,
2142 `recievedlist` longtext NOT NULL,
2143 `opacnote` varchar(150) NOT NULL default '',
2144 `librariannote` varchar(150) NOT NULL default '',
2145 PRIMARY KEY (`subscriptionid`),
2146 KEY `biblionumber` (`biblionumber`)
2147 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2150 -- Table structure for table `subscriptionroutinglist`
2153 DROP TABLE IF EXISTS `subscriptionroutinglist`;
2154 CREATE TABLE `subscriptionroutinglist` ( -- information related to the routing lists attached to subscriptions
2155 `routingid` int(11) NOT NULL auto_increment, -- unique identifier assigned by Koha
2156 `borrowernumber` int(11) NOT NULL, -- foreign key from the borrowers table, defines with patron is on the routing list
2157 `ranking` int(11) default NULL, -- where the patron stands in line to receive the serial
2158 `subscriptionid` int(11) NOT NULL, -- foreign key from the subscription table, defines which subscription this routing list is for
2159 PRIMARY KEY (`routingid`),
2160 UNIQUE (`subscriptionid`, `borrowernumber`),
2161 CONSTRAINT `subscriptionroutinglist_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`)
2162 ON DELETE CASCADE ON UPDATE CASCADE,
2163 CONSTRAINT `subscriptionroutinglist_ibfk_2` FOREIGN KEY (`subscriptionid`) REFERENCES `subscription` (`subscriptionid`)
2164 ON DELETE CASCADE ON UPDATE CASCADE
2165 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2168 -- Table structure for table `suggestions`
2171 DROP TABLE IF EXISTS `suggestions`;
2172 CREATE TABLE `suggestions` ( -- purchase suggestions
2173 `suggestionid` int(8) NOT NULL auto_increment, -- unique identifier assigned automatically by Koha
2174 `suggestedby` int(11) NOT NULL default 0, -- borrowernumber for the person making the suggestion, foreign key linking to the borrowers table
2175 `suggesteddate` date NOT NULL, -- date the suggestion was submitted
2176 `managedby` int(11) default NULL, -- borrowernumber for the librarian managing the suggestion, foreign key linking to the borrowers table
2177 `manageddate` date default NULL, -- date the suggestion was updated
2178 acceptedby INT(11) default NULL, -- borrowernumber for the librarian who accepted the suggestion, foreign key linking to the borrowers table
2179 accepteddate date default NULL, -- date the suggestion was marked as accepted
2180 rejectedby INT(11) default NULL, -- borrowernumber for the librarian who rejected the suggestion, foreign key linking to the borrowers table
2181 rejecteddate date default NULL, -- date the suggestion was marked as rejected
2182 `STATUS` varchar(10) NOT NULL default '', -- suggestion status (ASKED, CHECKED, ACCEPTED, or REJECTED)
2183 `note` mediumtext, -- note entered on the suggestion
2184 `author` varchar(80) default NULL, -- author of the suggested item
2185 `title` varchar(255) default NULL, -- title of the suggested item
2186 `copyrightdate` smallint(6) default NULL, -- copyright date of the suggested item
2187 `publishercode` varchar(255) default NULL, -- publisher of the suggested item
2188 `date` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- date and time the suggestion was updated
2189 `volumedesc` varchar(255) default NULL,
2190 `publicationyear` smallint(6) default 0,
2191 `place` varchar(255) default NULL, -- publication place of the suggested item
2192 `isbn` varchar(30) default NULL, -- isbn of the suggested item
2193 `biblionumber` int(11) default NULL, -- foreign key linking the suggestion to the biblio table after the suggestion has been ordered
2194 `reason` text, -- reason for accepting or rejecting the suggestion
2195 `patronreason` text, -- reason for making the suggestion
2196 budgetid INT(11), -- foreign key linking the suggested budget to the aqbudgets table
2197 branchcode VARCHAR(10) default NULL, -- foreign key linking the suggested branch to the branches table
2198 collectiontitle text default NULL, -- collection name for the suggested item
2199 itemtype VARCHAR(30) default NULL, -- suggested item type
2200 quantity SMALLINT(6) default NULL, -- suggested quantity to be purchased
2201 currency VARCHAR(3) default NULL, -- suggested currency for the suggested price
2202 price DECIMAL(28,6) default NULL, -- suggested price
2203 total DECIMAL(28,6) default NULL, -- suggested total cost (price*quantity updated for currency)
2204 PRIMARY KEY (`suggestionid`),
2205 KEY `suggestedby` (`suggestedby`),
2206 KEY `managedby` (`managedby`),
2207 KEY `status` (`STATUS`),
2208 KEY `biblionumber` (`biblionumber`),
2209 KEY `branchcode` (`branchcode`),
2210 CONSTRAINT `suggestions_budget_id_fk` FOREIGN KEY (`budgetid`) REFERENCES `aqbudgets` (`budget_id`) ON DELETE SET NULL ON UPDATE CASCADE
2211 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2214 -- Table structure for table `systempreferences`
2217 DROP TABLE IF EXISTS `systempreferences`;
2218 CREATE TABLE `systempreferences` ( -- global system preferences
2219 `variable` varchar(50) NOT NULL default '', -- system preference name
2220 `value` text, -- system preference values
2221 `options` mediumtext, -- options for multiple choice system preferences
2222 `explanation` text, -- descriptive text for the system preference
2223 `type` varchar(20) default NULL, -- type of question this preference asks (multiple choice, plain text, yes or no, etc)
2224 PRIMARY KEY (`variable`)
2225 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2228 -- Table structure for table `tags`
2231 DROP TABLE IF EXISTS `tags`;
2232 CREATE TABLE `tags` (
2233 `entry` varchar(255) NOT NULL default '',
2234 `weight` bigint(20) NOT NULL default 0,
2235 PRIMARY KEY (`entry`)
2236 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2239 -- Table structure for table `tags_all`
2242 DROP TABLE IF EXISTS `tags_all`;
2243 CREATE TABLE `tags_all` ( -- all of the tags
2244 `tag_id` int(11) NOT NULL auto_increment, -- unique id and primary key
2245 `borrowernumber` int(11) NOT NULL, -- the patron who added the tag (borrowers.borrowernumber)
2246 `biblionumber` int(11) NOT NULL, -- the bib record this tag was left on (biblio.biblionumber)
2247 `term` varchar(255) NOT NULL, -- the tag
2248 `language` int(4) default NULL, -- the language the tag was left in
2249 `date_created` datetime NOT NULL, -- the date the tag was added
2250 PRIMARY KEY (`tag_id`),
2251 KEY `tags_borrowers_fk_1` (`borrowernumber`),
2252 KEY `tags_biblionumber_fk_1` (`biblionumber`),
2253 CONSTRAINT `tags_borrowers_fk_1` FOREIGN KEY (`borrowernumber`)
2254 REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE,
2255 CONSTRAINT `tags_biblionumber_fk_1` FOREIGN KEY (`biblionumber`)
2256 REFERENCES `biblio` (`biblionumber`) ON DELETE CASCADE ON UPDATE CASCADE
2257 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2260 -- Table structure for table `tags_approval`
2263 DROP TABLE IF EXISTS `tags_approval`;
2264 CREATE TABLE `tags_approval` ( -- approved tags
2265 `term` varchar(255) NOT NULL, -- the tag
2266 `approved` int(1) NOT NULL default '0', -- whether the tag is approved or not (1=yes, 0=pending, -1=rejected)
2267 `date_approved` datetime default NULL, -- the date this tag was approved
2268 `approved_by` int(11) default NULL, -- the librarian who approved the tag (borrowers.borrowernumber)
2269 `weight_total` int(9) NOT NULL default '1', -- the total number of times this tag was used
2270 PRIMARY KEY (`term`),
2271 KEY `tags_approval_borrowers_fk_1` (`approved_by`),
2272 CONSTRAINT `tags_approval_borrowers_fk_1` FOREIGN KEY (`approved_by`)
2273 REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE
2274 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2277 -- Table structure for table `tags_index`
2280 DROP TABLE IF EXISTS `tags_index`;
2281 CREATE TABLE `tags_index` ( -- a weighted list of all tags and where they are used
2282 `term` varchar(255) NOT NULL, -- the tag
2283 `biblionumber` int(11) NOT NULL, -- the bib record this tag was used on (biblio.biblionumber)
2284 `weight` int(9) NOT NULL default '1', -- the number of times this term was used on this bib record
2285 PRIMARY KEY (`term`,`biblionumber`),
2286 KEY `tags_index_biblionumber_fk_1` (`biblionumber`),
2287 CONSTRAINT `tags_index_term_fk_1` FOREIGN KEY (`term`)
2288 REFERENCES `tags_approval` (`term`) ON DELETE CASCADE ON UPDATE CASCADE,
2289 CONSTRAINT `tags_index_biblionumber_fk_1` FOREIGN KEY (`biblionumber`)
2290 REFERENCES `biblio` (`biblionumber`) ON DELETE CASCADE ON UPDATE CASCADE
2291 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2294 -- Table structure for table `userflags`
2297 DROP TABLE IF EXISTS `userflags`;
2298 CREATE TABLE `userflags` (
2299 `bit` int(11) NOT NULL default 0,
2300 `flag` varchar(30) default NULL,
2301 `flagdesc` varchar(255) default NULL,
2302 `defaulton` int(11) default NULL,
2304 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2307 -- Table structure for table `virtualshelves`
2310 DROP TABLE IF EXISTS `virtualshelves`;
2311 CREATE TABLE `virtualshelves` ( -- information about lists (or virtual shelves)
2312 `shelfnumber` int(11) NOT NULL auto_increment, -- unique identifier assigned by Koha
2313 `shelfname` varchar(255) default NULL, -- name of the list
2314 `owner` int default NULL, -- foreign key linking to the borrowers table (using borrowernumber) for the creator of this list (changed from varchar(80) to int)
2315 `category` varchar(1) default NULL, -- type of list (private [1], public [2])
2316 `sortfield` varchar(16) default NULL, -- the field this list is sorted on
2317 `lastmodified` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- date and time the list was last modified
2318 `created_on` TIMESTAMP NOT NULL, -- creation time
2319 `allow_add` tinyint(1) default 0, -- permission for adding entries to list
2320 `allow_delete_own` tinyint(1) default 1, -- permission for deleting entries frm list that you added yourself
2321 `allow_delete_other` tinyint(1) default 0, -- permission for deleting entries from list that another person added
2322 PRIMARY KEY (`shelfnumber`),
2323 CONSTRAINT `virtualshelves_ibfk_1` FOREIGN KEY (`owner`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE SET NULL ON UPDATE SET NULL -- no cascaded delete, please see HandleDelBorrower in VirtualShelves.pm
2324 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2327 -- Table structure for table `virtualshelfcontents`
2330 DROP TABLE IF EXISTS `virtualshelfcontents`;
2331 CREATE TABLE `virtualshelfcontents` ( -- information about the titles in a list (or virtual shelf)
2332 `shelfnumber` int(11) NOT NULL default 0, -- foreign key linking to the virtualshelves table, defines the list that this record has been added to
2333 `biblionumber` int(11) NOT NULL default 0, -- foreign key linking to the biblio table, defines the bib record that has been added to the list
2334 `flags` int(11) default NULL,
2335 `dateadded` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, -- date and time this bib record was added to the list
2336 `borrowernumber` int, -- borrower number that created this list entry (only the first one is saved: no need for use in/as key)
2337 KEY `shelfnumber` (`shelfnumber`),
2338 KEY `biblionumber` (`biblionumber`),
2339 CONSTRAINT `virtualshelfcontents_ibfk_1` FOREIGN KEY (`shelfnumber`) REFERENCES `virtualshelves` (`shelfnumber`) ON DELETE CASCADE ON UPDATE CASCADE,
2340 CONSTRAINT `shelfcontents_ibfk_2` FOREIGN KEY (`biblionumber`) REFERENCES `biblio` (`biblionumber`) ON DELETE CASCADE ON UPDATE CASCADE,
2341 CONSTRAINT `shelfcontents_ibfk_3` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE SET NULL ON UPDATE SET NULL -- no cascaded delete, please see HandleDelBorrower in VirtualShelves.pm
2342 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2345 -- Table structure for table `virtualshelfshares`
2348 DROP TABLE IF EXISTS `virtualshelfshares`;
2349 CREATE TABLE `virtualshelfshares` ( -- shared private lists
2350 `id` int AUTO_INCREMENT PRIMARY KEY, -- unique key
2351 `shelfnumber` int NOT NULL, -- foreign key for virtualshelves
2352 `borrowernumber` int, -- borrower that accepted access to this list
2353 `invitekey` varchar(10), -- temporary string used in accepting the invitation to access thist list; not-empty means that the invitation has not been accepted yet
2354 `sharedate` datetime, -- date of invitation or acceptance of invitation
2355 CONSTRAINT `virtualshelfshares_ibfk_1` FOREIGN KEY (`shelfnumber`) REFERENCES `virtualshelves` (`shelfnumber`) ON DELETE CASCADE ON UPDATE CASCADE,
2356 CONSTRAINT `virtualshelfshares_ibfk_2` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE SET NULL ON UPDATE SET NULL -- no cascaded delete, please see HandleDelBorrower in VirtualShelves.pm
2357 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2360 -- Table structure for table `z3950servers`
2363 DROP TABLE IF EXISTS `z3950servers`;
2364 CREATE TABLE `z3950servers` ( -- connection information for the Z39.50 targets used in cataloging
2365 `id` int(11) NOT NULL auto_increment, -- unique identifier assigned by Koha
2366 `host` varchar(255) default NULL, -- target's host name
2367 `port` int(11) default NULL, -- port number used to connect to target
2368 `db` varchar(255) default NULL, -- target's database name
2369 `userid` varchar(255) default NULL, -- username needed to log in to target
2370 `password` varchar(255) default NULL, -- password needed to log in to target
2371 `servername` mediumtext NOT NULL, -- name given to the target by the library
2372 `checked` smallint(6) default NULL, -- whether this target is checked by default (1 for yes, 0 for no)
2373 `rank` int(11) default NULL, -- where this target appears in the list of targets
2374 `syntax` varchar(80) default NULL, -- marc format provided by this target
2375 `timeout` int(11) NOT NULL DEFAULT '0', -- number of seconds before Koha stops trying to access this server
2376 `servertype` enum('zed','sru') NOT NULL default 'zed', -- zed means z39.50 server
2377 `encoding` text default NULL, -- characters encoding provided by this target
2378 `recordtype` enum('authority','biblio') NOT NULL default 'biblio', -- server contains bibliographic or authority records
2379 `sru_options` varchar(255) default NULL, -- options like sru=get, sru_version=1.1; will be passed to the server via ZOOM
2380 `sru_fields` mediumtext default NULL, -- contains the mapping between the Z3950 search fields and the specific SRU server indexes
2381 `add_xslt` mediumtext default NULL, -- zero or more paths to XSLT files to be processed on the search results
2383 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2386 -- Table structure for table `zebraqueue`
2389 DROP TABLE IF EXISTS `zebraqueue`;
2390 CREATE TABLE `zebraqueue` (
2391 `id` int(11) NOT NULL auto_increment,
2392 `biblio_auth_number` bigint(20) unsigned NOT NULL default '0',
2393 `operation` char(20) NOT NULL default '',
2394 `server` char(20) NOT NULL default '',
2395 `done` int(11) NOT NULL default '0',
2396 `time` timestamp NOT NULL default CURRENT_TIMESTAMP,
2398 KEY `zebraqueue_lookup` (`server`, `biblio_auth_number`, `operation`, `done`)
2399 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2402 -- Table structure for table `services_throttle`
2405 DROP TABLE IF EXISTS `services_throttle`;
2406 CREATE TABLE `services_throttle` (
2407 `service_type` varchar(10) NOT NULL default '',
2408 `service_count` varchar(45) default NULL,
2409 PRIMARY KEY (`service_type`)
2410 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2413 -- Table structure for table `language_subtag_registry`
2414 -- http://www.w3.org/International/articles/language-tags/
2418 DROP TABLE IF EXISTS language_subtag_registry;
2419 CREATE TABLE language_subtag_registry (
2421 type varchar(25), -- language-script-region-variant-extension-privateuse
2422 description varchar(25), -- only one of the possible descriptions for ease of reference, see language_descriptions for the complete list
2424 id int(11) NOT NULL auto_increment,
2426 KEY `subtag` (`subtag`)
2427 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2430 -- Table structure for table `language_rfc4646_to_iso639`
2431 -- TODO: add suppress_scripts
2432 -- this maps three letter codes defined in iso639.2 back to their
2433 -- two letter equivilents in rfc4646 (LOC maintains iso639+)
2436 DROP TABLE IF EXISTS language_rfc4646_to_iso639;
2437 CREATE TABLE language_rfc4646_to_iso639 (
2438 rfc4646_subtag varchar(25),
2439 iso639_2_code varchar(25),
2440 id int(11) NOT NULL auto_increment,
2442 KEY `rfc4646_subtag` (`rfc4646_subtag`)
2443 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2446 -- Table structure for table `language_descriptions`
2449 DROP TABLE IF EXISTS language_descriptions;
2450 CREATE TABLE language_descriptions (
2454 description varchar(255),
2455 id int(11) NOT NULL auto_increment,
2457 KEY `lang` (`lang`),
2458 KEY `subtag_type_lang` (`subtag`, `type`, `lang`)
2459 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2462 -- Table structure for table `language_script_bidi`
2463 -- bi-directional support, keyed by script subcode
2466 DROP TABLE IF EXISTS language_script_bidi;
2467 CREATE TABLE language_script_bidi (
2468 rfc4646_subtag varchar(25), -- script subtag, Arab, Hebr, etc.
2469 bidi varchar(3), -- rtl ltr
2470 KEY `rfc4646_subtag` (`rfc4646_subtag`)
2471 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2474 -- Table structure for table `language_script_mapping`
2475 -- TODO: need to map language subtags to script subtags for detection
2476 -- of bidi when script is not specified (like ar, he)
2479 DROP TABLE IF EXISTS language_script_mapping;
2480 CREATE TABLE language_script_mapping (
2481 language_subtag varchar(25),
2482 script_subtag varchar(25),
2483 KEY `language_subtag` (`language_subtag`)
2484 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2487 -- Table structure for table `permissions`
2490 DROP TABLE IF EXISTS `permissions`;
2491 CREATE TABLE `permissions` (
2492 `module_bit` int(11) NOT NULL DEFAULT 0,
2493 `code` varchar(64) DEFAULT NULL,
2494 `description` varchar(255) DEFAULT NULL,
2495 PRIMARY KEY (`module_bit`, `code`),
2496 CONSTRAINT `permissions_ibfk_1` FOREIGN KEY (`module_bit`) REFERENCES `userflags` (`bit`)
2497 ON DELETE CASCADE ON UPDATE CASCADE
2498 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2501 -- Table structure for table `serialitems`
2504 DROP TABLE IF EXISTS `serialitems`;
2505 CREATE TABLE `serialitems` (
2506 `itemnumber` int(11) NOT NULL,
2507 `serialid` int(11) NOT NULL,
2508 UNIQUE KEY `serialitemsidx` (`itemnumber`),
2509 KEY `serialitems_sfk_1` (`serialid`),
2510 CONSTRAINT `serialitems_sfk_1` FOREIGN KEY (`serialid`) REFERENCES `serial` (`serialid`) ON DELETE CASCADE ON UPDATE CASCADE,
2511 CONSTRAINT `serialitems_sfk_2` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`) ON DELETE CASCADE ON UPDATE CASCADE
2512 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2515 -- Table structure for table `user_permissions`
2518 DROP TABLE IF EXISTS `user_permissions`;
2519 CREATE TABLE `user_permissions` (
2520 `borrowernumber` int(11) NOT NULL DEFAULT 0,
2521 `module_bit` int(11) NOT NULL DEFAULT 0,
2522 `code` varchar(64) DEFAULT NULL,
2523 CONSTRAINT `user_permissions_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`)
2524 ON DELETE CASCADE ON UPDATE CASCADE,
2525 CONSTRAINT `user_permissions_ibfk_2` FOREIGN KEY (`module_bit`, `code`) REFERENCES `permissions` (`module_bit`, `code`)
2526 ON DELETE CASCADE ON UPDATE CASCADE
2527 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2530 -- Table structure for table `tmp_holdsqueue`
2533 DROP TABLE IF EXISTS `tmp_holdsqueue`;
2534 CREATE TABLE `tmp_holdsqueue` (
2535 `biblionumber` int(11) default NULL,
2536 `itemnumber` int(11) default NULL,
2537 `barcode` varchar(20) default NULL,
2538 `surname` mediumtext NOT NULL,
2541 `borrowernumber` int(11) NOT NULL,
2542 `cardnumber` varchar(16) default NULL,
2543 `reservedate` date default NULL,
2545 `itemcallnumber` varchar(255) default NULL,
2546 `holdingbranch` varchar(10) default NULL,
2547 `pickbranch` varchar(10) default NULL,
2549 `item_level_request` tinyint(4) NOT NULL default 0
2550 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2553 -- Table structure for table `message_queue`
2556 DROP TABLE IF EXISTS `message_queue`;
2557 CREATE TABLE `message_queue` (
2558 `message_id` int(11) NOT NULL auto_increment,
2559 `borrowernumber` int(11) default NULL,
2562 `metadata` text DEFAULT NULL,
2563 `letter_code` varchar(64) DEFAULT NULL,
2564 `message_transport_type` varchar(20) NOT NULL,
2565 `status` enum('sent','pending','failed','deleted') NOT NULL default 'pending',
2566 `time_queued` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
2567 `to_address` mediumtext,
2568 `from_address` mediumtext,
2569 `content_type` text,
2570 KEY `message_id` (`message_id`),
2571 KEY `borrowernumber` (`borrowernumber`),
2572 KEY `message_transport_type` (`message_transport_type`),
2573 CONSTRAINT `messageq_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE,
2574 CONSTRAINT `messageq_ibfk_2` FOREIGN KEY (`message_transport_type`) REFERENCES `message_transport_types` (`message_transport_type`) ON DELETE RESTRICT ON UPDATE CASCADE
2575 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2578 -- Table structure for table `message_transport_types`
2581 DROP TABLE IF EXISTS `message_transport_types`;
2582 CREATE TABLE `message_transport_types` (
2583 `message_transport_type` varchar(20) NOT NULL,
2584 PRIMARY KEY (`message_transport_type`)
2585 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2588 -- Table structure for table `overduerules_transport_types`
2591 DROP TABLE IF EXISTS `overduerules_transport_types`;
2592 CREATE TABLE overduerules_transport_types(
2593 `id` INT(11) NOT NULL AUTO_INCREMENT,
2594 `branchcode` varchar(10) NOT NULL DEFAULT '',
2595 `categorycode` VARCHAR(10) NOT NULL DEFAULT '',
2596 `letternumber` INT(1) NOT NULL DEFAULT 1,
2597 `message_transport_type` VARCHAR(20) NOT NULL DEFAULT 'email',
2599 CONSTRAINT overduerules_fk FOREIGN KEY (branchcode, categorycode) REFERENCES overduerules (branchcode, categorycode) ON DELETE CASCADE ON UPDATE CASCADE,
2600 CONSTRAINT mtt_fk FOREIGN KEY (message_transport_type) REFERENCES message_transport_types (message_transport_type) ON DELETE CASCADE ON UPDATE CASCADE
2601 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2604 -- Table structure for table `message_attributes`
2607 DROP TABLE IF EXISTS `message_attributes`;
2608 CREATE TABLE `message_attributes` (
2609 `message_attribute_id` int(11) NOT NULL auto_increment,
2610 `message_name` varchar(40) NOT NULL default '',
2611 `takes_days` tinyint(1) NOT NULL default '0',
2612 PRIMARY KEY (`message_attribute_id`),
2613 UNIQUE KEY `message_name` (`message_name`)
2614 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2617 -- Table structure for table `message_transports`
2620 DROP TABLE IF EXISTS `message_transports`;
2621 CREATE TABLE `message_transports` (
2622 `message_attribute_id` int(11) NOT NULL,
2623 `message_transport_type` varchar(20) NOT NULL,
2624 `is_digest` tinyint(1) NOT NULL default '0',
2625 `letter_module` varchar(20) NOT NULL default '',
2626 `letter_code` varchar(20) NOT NULL default '',
2627 `branchcode` varchar(10) NOT NULL default '',
2628 PRIMARY KEY (`message_attribute_id`,`message_transport_type`,`is_digest`),
2629 KEY `message_transport_type` (`message_transport_type`),
2630 KEY `letter_module` (`letter_module`,`letter_code`),
2631 CONSTRAINT `message_transports_ibfk_1` FOREIGN KEY (`message_attribute_id`) REFERENCES `message_attributes` (`message_attribute_id`) ON DELETE CASCADE ON UPDATE CASCADE,
2632 CONSTRAINT `message_transports_ibfk_2` FOREIGN KEY (`message_transport_type`) REFERENCES `message_transport_types` (`message_transport_type`) ON DELETE CASCADE ON UPDATE CASCADE,
2633 CONSTRAINT `message_transports_ibfk_3` FOREIGN KEY (`letter_module`, `letter_code`, `branchcode`) REFERENCES `letter` (`module`, `code`, `branchcode`) ON DELETE CASCADE ON UPDATE CASCADE
2634 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2637 -- Table structure for table `borrower_files`
2640 DROP TABLE IF EXISTS `borrower_files`;
2641 CREATE TABLE IF NOT EXISTS `borrower_files` ( -- files attached to the patron/borrower record
2642 `file_id` int(11) NOT NULL AUTO_INCREMENT, -- unique key
2643 `borrowernumber` int(11) NOT NULL, -- foreign key linking to the patron via the borrowernumber
2644 `file_name` varchar(255) NOT NULL, -- file name
2645 `file_type` varchar(255) NOT NULL, -- type of file
2646 `file_description` varchar(255) DEFAULT NULL, -- description given to the file
2647 `file_content` longblob NOT NULL, -- the file
2648 `date_uploaded` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, -- date and time the file was added
2649 PRIMARY KEY (`file_id`),
2650 KEY `borrowernumber` (`borrowernumber`),
2651 CONSTRAINT borrower_files_ibfk_1 FOREIGN KEY (borrowernumber) REFERENCES borrowers (borrowernumber) ON DELETE CASCADE ON UPDATE CASCADE
2652 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2655 -- Table structure for table `borrower_message_preferences`
2658 DROP TABLE IF EXISTS `borrower_message_preferences`;
2659 CREATE TABLE `borrower_message_preferences` (
2660 `borrower_message_preference_id` int(11) NOT NULL auto_increment,
2661 `borrowernumber` int(11) default NULL,
2662 `categorycode` varchar(10) default NULL,
2663 `message_attribute_id` int(11) default '0',
2664 `days_in_advance` int(11) default '0',
2665 `wants_digest` tinyint(1) NOT NULL default '0',
2666 PRIMARY KEY (`borrower_message_preference_id`),
2667 KEY `borrowernumber` (`borrowernumber`),
2668 KEY `categorycode` (`categorycode`),
2669 KEY `message_attribute_id` (`message_attribute_id`),
2670 CONSTRAINT `borrower_message_preferences_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE,
2671 CONSTRAINT `borrower_message_preferences_ibfk_2` FOREIGN KEY (`message_attribute_id`) REFERENCES `message_attributes` (`message_attribute_id`) ON DELETE CASCADE ON UPDATE CASCADE,
2672 CONSTRAINT `borrower_message_preferences_ibfk_3` FOREIGN KEY (`categorycode`) REFERENCES `categories` (`categorycode`) ON DELETE CASCADE ON UPDATE CASCADE
2673 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2676 -- Table structure for table `borrower_message_transport_preferences`
2679 DROP TABLE IF EXISTS `borrower_message_transport_preferences`;
2680 CREATE TABLE `borrower_message_transport_preferences` (
2681 `borrower_message_preference_id` int(11) NOT NULL default '0',
2682 `message_transport_type` varchar(20) NOT NULL default '0',
2683 PRIMARY KEY (`borrower_message_preference_id`,`message_transport_type`),
2684 KEY `message_transport_type` (`message_transport_type`),
2685 CONSTRAINT `borrower_message_transport_preferences_ibfk_1` FOREIGN KEY (`borrower_message_preference_id`) REFERENCES `borrower_message_preferences` (`borrower_message_preference_id`) ON DELETE CASCADE ON UPDATE CASCADE,
2686 CONSTRAINT `borrower_message_transport_preferences_ibfk_2` FOREIGN KEY (`message_transport_type`) REFERENCES `message_transport_types` (`message_transport_type`) ON DELETE CASCADE ON UPDATE CASCADE
2687 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2690 -- Table structure for the table branch_transfer_limits
2693 DROP TABLE IF EXISTS `branch_transfer_limits`;
2694 CREATE TABLE branch_transfer_limits (
2695 limitId int(8) NOT NULL auto_increment,
2696 toBranch varchar(10) NOT NULL,
2697 fromBranch varchar(10) NOT NULL,
2698 itemtype varchar(10) NULL,
2699 ccode varchar(10) NULL,
2700 PRIMARY KEY (limitId)
2701 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2704 -- Table structure for table `item_circulation_alert_preferences`
2707 DROP TABLE IF EXISTS `item_circulation_alert_preferences`;
2708 CREATE TABLE `item_circulation_alert_preferences` (
2709 `id` int(11) NOT NULL auto_increment,
2710 `branchcode` varchar(10) NOT NULL,
2711 `categorycode` varchar(10) NOT NULL,
2712 `item_type` varchar(10) NOT NULL,
2713 `notification` varchar(16) NOT NULL,
2715 KEY `branchcode` (`branchcode`,`categorycode`,`item_type`, `notification`)
2716 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2719 -- Table structure for table `messages`
2721 DROP TABLE IF EXISTS `messages`;
2722 CREATE TABLE `messages` ( -- circulation messages left via the patron's check out screen
2723 `message_id` int(11) NOT NULL auto_increment, -- unique identifier assigned by Koha
2724 `borrowernumber` int(11) NOT NULL, -- foreign key linking this message to the borrowers table
2725 `branchcode` varchar(10) default NULL, -- foreign key linking the message to the branches table
2726 `message_type` varchar(1) NOT NULL, -- whether the message is for the librarians (L) or the patron (B)
2727 `message` text NOT NULL, -- the text of the message
2728 `message_date` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, -- the date and time the message was written
2729 PRIMARY KEY (`message_id`)
2730 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2733 -- Table structure for table `accountlines`
2736 DROP TABLE IF EXISTS `accountlines`;
2737 CREATE TABLE `accountlines` (
2738 `accountlines_id` int(11) NOT NULL AUTO_INCREMENT,
2739 `borrowernumber` int(11) NOT NULL default 0,
2740 `accountno` smallint(6) NOT NULL default 0,
2741 `itemnumber` int(11) default NULL,
2742 `date` date default NULL,
2743 `amount` decimal(28,6) default NULL,
2744 `description` mediumtext,
2745 `dispute` mediumtext,
2746 `accounttype` varchar(5) default NULL,
2747 `amountoutstanding` decimal(28,6) default NULL,
2748 `lastincrement` decimal(28,6) default NULL,
2749 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
2750 `notify_id` int(11) NOT NULL default 0,
2751 `notify_level` int(2) NOT NULL default 0,
2752 `note` text NULL default NULL,
2753 `manager_id` int(11) NULL,
2754 PRIMARY KEY (`accountlines_id`),
2755 KEY `acctsborridx` (`borrowernumber`),
2756 KEY `timeidx` (`timestamp`),
2757 KEY `itemnumber` (`itemnumber`),
2758 CONSTRAINT `accountlines_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE,
2759 CONSTRAINT `accountlines_ibfk_2` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`) ON DELETE SET NULL ON UPDATE SET NULL
2760 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2763 -- Table structure for table `accountoffsets`
2766 DROP TABLE IF EXISTS `accountoffsets`;
2767 CREATE TABLE `accountoffsets` (
2768 `borrowernumber` int(11) NOT NULL default 0,
2769 `accountno` smallint(6) NOT NULL default 0,
2770 `offsetaccount` smallint(6) NOT NULL default 0,
2771 `offsetamount` decimal(28,6) default NULL,
2772 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
2773 CONSTRAINT `accountoffsets_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE
2774 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2777 -- Table structure for table `action_logs`
2780 DROP TABLE IF EXISTS `action_logs`;
2781 CREATE TABLE `action_logs` ( -- logs of actions taken in Koha (requires that the logs be turned on)
2782 `action_id` int(11) NOT NULL auto_increment, -- unique identifier for each action
2783 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- the date and time the action took place
2784 `user` int(11) NOT NULL default 0, -- the staff member who performed the action (borrowers.borrowernumber)
2785 `module` text, -- the module this action was taken against
2786 `action` text, -- the action (includes things like DELETED, ADDED, MODIFY, etc)
2787 `object` int(11) default NULL, -- the object that the action was taken against (could be a borrowernumber, itemnumber, etc)
2788 `info` text, -- information about the action (usually includes SQL statement)
2789 PRIMARY KEY (`action_id`),
2790 KEY `timestamp_idx` (`timestamp`),
2791 KEY `user_idx` (`user`),
2792 KEY `module_idx` (`module`(255)),
2793 KEY `action_idx` (`action`(255)),
2794 KEY `object_idx` (`object`),
2795 KEY `info_idx` (`info`(255))
2796 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2799 -- Table structure for table `alert`
2802 DROP TABLE IF EXISTS `alert`;
2803 CREATE TABLE `alert` (
2804 `alertid` int(11) NOT NULL auto_increment,
2805 `borrowernumber` int(11) NOT NULL default 0,
2806 `type` varchar(10) NOT NULL default '',
2807 `externalid` varchar(20) NOT NULL default '',
2808 PRIMARY KEY (`alertid`),
2809 KEY `borrowernumber` (`borrowernumber`),
2810 KEY `type` (`type`,`externalid`)
2811 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2814 -- Table structure for table `aqbasketgroups`
2817 DROP TABLE IF EXISTS `aqbasketgroups`;
2818 CREATE TABLE `aqbasketgroups` (
2819 `id` int(11) NOT NULL auto_increment,
2820 `name` varchar(50) default NULL,
2821 `closed` tinyint(1) default NULL,
2822 `booksellerid` int(11) NOT NULL,
2823 `deliveryplace` varchar(10) default NULL,
2824 `freedeliveryplace` text default NULL,
2825 `deliverycomment` varchar(255) default NULL,
2826 `billingplace` varchar(10) default NULL,
2828 KEY `booksellerid` (`booksellerid`),
2829 CONSTRAINT `aqbasketgroups_ibfk_1` FOREIGN KEY (`booksellerid`) REFERENCES `aqbooksellers` (`id`) ON UPDATE CASCADE ON DELETE CASCADE
2830 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2833 -- Table structure for table `aqbasket`
2836 DROP TABLE IF EXISTS `aqbasket`;
2837 CREATE TABLE `aqbasket` ( -- stores data about baskets in acquisitions
2838 `basketno` int(11) NOT NULL auto_increment, -- primary key, Koha defined number
2839 `basketname` varchar(50) default NULL, -- name given to the basket at creation
2840 `note` mediumtext, -- the internal note added at basket creation
2841 `booksellernote` mediumtext, -- the vendor note added at basket creation
2842 `contractnumber` int(11), -- links this basket to the aqcontract table (aqcontract.contractnumber)
2843 `creationdate` date default NULL, -- the date the basket was created
2844 `closedate` date default NULL, -- the date the basket was closed
2845 `booksellerid` int(11) NOT NULL default 1, -- the Koha assigned ID for the vendor (aqbooksellers.id)
2846 `authorisedby` varchar(10) default NULL, -- the borrowernumber of the person who created the basket
2847 `booksellerinvoicenumber` mediumtext, -- appears to always be NULL
2848 `basketgroupid` int(11), -- links this basket to its group (aqbasketgroups.id)
2849 `deliveryplace` varchar(10) default NULL, -- basket delivery place
2850 `billingplace` varchar(10) default NULL, -- basket billing place
2851 branch varchar(10) default NULL, -- basket branch
2852 PRIMARY KEY (`basketno`),
2853 KEY `booksellerid` (`booksellerid`),
2854 KEY `basketgroupid` (`basketgroupid`),
2855 KEY `contractnumber` (`contractnumber`),
2856 CONSTRAINT `aqbasket_ibfk_1` FOREIGN KEY (`booksellerid`) REFERENCES `aqbooksellers` (`id`) ON UPDATE CASCADE,
2857 CONSTRAINT `aqbasket_ibfk_2` FOREIGN KEY (`contractnumber`) REFERENCES `aqcontract` (`contractnumber`),
2858 CONSTRAINT `aqbasket_ibfk_3` FOREIGN KEY (`basketgroupid`) REFERENCES `aqbasketgroups` (`id`) ON UPDATE CASCADE,
2859 CONSTRAINT aqbasket_ibfk_4 FOREIGN KEY (branch) REFERENCES branches (branchcode) ON UPDATE CASCADE ON DELETE SET NULL
2860 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2863 -- Table structure for table aqbasketusers
2866 DROP TABLE IF EXISTS aqbasketusers;
2867 CREATE TABLE aqbasketusers (
2868 basketno int(11) NOT NULL,
2869 borrowernumber int(11) NOT NULL,
2870 PRIMARY KEY (basketno,borrowernumber),
2871 CONSTRAINT aqbasketusers_ibfk_1 FOREIGN KEY (basketno) REFERENCES aqbasket (basketno) ON UPDATE CASCADE ON DELETE CASCADE,
2872 CONSTRAINT aqbasketusers_ibfk_2 FOREIGN KEY (borrowernumber) REFERENCES borrowers (borrowernumber) ON UPDATE CASCADE ON DELETE CASCADE
2873 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2876 -- Table structure for table `aqbooksellers`
2879 DROP TABLE IF EXISTS `aqbooksellers`;
2880 CREATE TABLE `aqbooksellers` ( -- information about the vendors listed in acquisitions
2881 `id` int(11) NOT NULL auto_increment, -- primary key and unique identifier assigned by Koha
2882 `name` mediumtext NOT NULL, -- vendor name
2883 `address1` mediumtext, -- first line of vendor physical address
2884 `address2` mediumtext, -- second line of vendor physical address
2885 `address3` mediumtext, -- third line of vendor physical address
2886 `address4` mediumtext, -- fourth line of vendor physical address
2887 `phone` varchar(30) default NULL, -- vendor phone number
2888 `accountnumber` mediumtext, -- unused in Koha
2889 `othersupplier` mediumtext, -- unused in Koha
2890 `currency` varchar(3) NOT NULL default '', -- unused in Koha
2891 `booksellerfax` mediumtext, -- vendor fax number
2892 `notes` mediumtext, -- order notes
2893 `bookselleremail` mediumtext, -- vendor email
2894 `booksellerurl` mediumtext, -- unused in Koha
2895 `postal` mediumtext, -- vendor postal address (all lines)
2896 `url` varchar(255) default NULL, -- vendor web address
2897 `active` tinyint(4) default NULL, -- is this vendor active (1 for yes, 0 for no)
2898 `listprice` varchar(10) default NULL, -- currency code for list prices
2899 `invoiceprice` varchar(10) default NULL, -- currency code for invoice prices
2900 `gstreg` tinyint(4) default NULL, -- is your library charged tax (1 for yes, 0 for no)
2901 `listincgst` tinyint(4) default NULL, -- is tax included in list prices (1 for yes, 0 for no)
2902 `invoiceincgst` tinyint(4) default NULL, -- is tax included in invoice prices (1 for yes, 0 for no)
2903 `gstrate` decimal(6,4) default NULL, -- the tax rate the library is charged
2904 `discount` float(6,4) default NULL, -- discount offered on all items ordered from this vendor
2905 `fax` varchar(50) default NULL, -- vendor fax number
2906 deliverytime int(11) default NULL, -- vendor delivery time
2908 KEY `listprice` (`listprice`),
2909 KEY `invoiceprice` (`invoiceprice`),
2910 CONSTRAINT `aqbooksellers_ibfk_1` FOREIGN KEY (`listprice`) REFERENCES `currency` (`currency`) ON DELETE CASCADE ON UPDATE CASCADE,
2911 CONSTRAINT `aqbooksellers_ibfk_2` FOREIGN KEY (`invoiceprice`) REFERENCES `currency` (`currency`) ON DELETE CASCADE ON UPDATE CASCADE
2912 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2915 -- Table structure for table `aqbudgets`
2918 DROP TABLE IF EXISTS `aqbudgets`;
2919 CREATE TABLE `aqbudgets` ( -- information related to Funds
2920 `budget_id` int(11) NOT NULL auto_increment, -- primary key and unique number assigned to each fund by Koha
2921 `budget_parent_id` int(11) default NULL, -- if this fund is a child of another this will include the parent id (aqbudgets.budget_id)
2922 `budget_code` varchar(30) default NULL, -- code assigned to the fund by the user
2923 `budget_name` varchar(80) default NULL, -- name assigned to the fund by the user
2924 `budget_branchcode` varchar(10) default NULL, -- branch that this fund belongs to (branches.branchcode)
2925 `budget_amount` decimal(28,6) NULL default '0.00', -- total amount for this fund
2926 `budget_encumb` decimal(28,6) NULL default '0.00', -- not used in the code
2927 `budget_expend` decimal(28,6) NULL default '0.00', -- not used in the code
2928 `budget_notes` mediumtext, -- notes related to this fund
2929 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- date and time this fund was last touched (created or modified)
2930 `budget_period_id` int(11) default NULL, -- id of the budget that this fund belongs to (aqbudgetperiods.budget_period_id)
2931 `sort1_authcat` varchar(80) default NULL, -- statistical category for this fund
2932 `sort2_authcat` varchar(80) default NULL, -- second statistical category for this fund
2933 `budget_owner_id` int(11) default NULL, -- borrowernumber of the person who owns this fund (borrowers.borrowernumber)
2934 `budget_permission` int(1) default '0', -- level of permission for this fund (used only by the owner, only by the library, or anyone)
2935 PRIMARY KEY (`budget_id`)
2936 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2939 -- Table structure for table aqbudgetborrowers
2942 DROP TABLE IF EXISTS aqbudgetborrowers;
2943 CREATE TABLE aqbudgetborrowers (
2944 budget_id int(11) NOT NULL,
2945 borrowernumber int(11) NOT NULL,
2946 PRIMARY KEY (budget_id, borrowernumber),
2947 CONSTRAINT aqbudgetborrowers_ibfk_1 FOREIGN KEY (budget_id)
2948 REFERENCES aqbudgets (budget_id)
2949 ON DELETE CASCADE ON UPDATE CASCADE,
2950 CONSTRAINT aqbudgetborrowers_ibfk_2 FOREIGN KEY (borrowernumber)
2951 REFERENCES borrowers (borrowernumber)
2952 ON DELETE CASCADE ON UPDATE CASCADE
2953 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2956 -- Table structure for table `aqbudgetperiods`
2960 DROP TABLE IF EXISTS `aqbudgetperiods`;
2961 CREATE TABLE `aqbudgetperiods` ( -- information related to Budgets
2962 `budget_period_id` int(11) NOT NULL auto_increment, -- primary key and unique number assigned by Koha
2963 `budget_period_startdate` date NOT NULL, -- date when the budget starts
2964 `budget_period_enddate` date NOT NULL, -- date when the budget ends
2965 `budget_period_active` tinyint(1) default '0', -- whether this budget is active or not (1 for yes, 0 for no)
2966 `budget_period_description` mediumtext, -- description assigned to this budget
2967 `budget_period_total` decimal(28,6), -- total amount available in this budget
2968 `budget_period_locked` tinyint(1) default NULL, -- whether this budget is locked or not (1 for yes, 0 for no)
2969 `sort1_authcat` varchar(10) default NULL, -- statistical category for this budget
2970 `sort2_authcat` varchar(10) default NULL, -- second statistical category for this budget
2971 PRIMARY KEY (`budget_period_id`)
2972 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2975 -- Table structure for table `aqbudgets_planning`
2978 DROP TABLE IF EXISTS `aqbudgets_planning`;
2979 CREATE TABLE `aqbudgets_planning` (
2980 `plan_id` int(11) NOT NULL auto_increment,
2981 `budget_id` int(11) NOT NULL,
2982 `budget_period_id` int(11) NOT NULL,
2983 `estimated_amount` decimal(28,6) default NULL,
2984 `authcat` varchar(30) NOT NULL,
2985 `authvalue` varchar(30) NOT NULL,
2986 `display` tinyint(1) DEFAULT 1,
2987 PRIMARY KEY (`plan_id`),
2988 CONSTRAINT `aqbudgets_planning_ifbk_1` FOREIGN KEY (`budget_id`) REFERENCES `aqbudgets` (`budget_id`) ON DELETE CASCADE ON UPDATE CASCADE
2989 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2992 -- Table structure for table 'aqcontacts'
2995 DROP TABLE IF EXISTS aqcontacts;
2996 CREATE TABLE aqcontacts (
2997 id int(11) NOT NULL auto_increment, -- primary key and unique number assigned by Koha
2998 name varchar(100) default NULL, -- name of contact at vendor
2999 position varchar(100) default NULL, -- contact person's position
3000 phone varchar(100) default NULL, -- contact's phone number
3001 altphone varchar(100) default NULL, -- contact's alternate phone number
3002 fax varchar(100) default NULL, -- contact's fax number
3003 email varchar(100) default NULL, -- contact's email address
3004 notes mediumtext, -- notes related to the contact
3005 claimacquisition BOOLEAN NOT NULL DEFAULT 0, -- should this contact receive acquisitions claims
3006 claimissues BOOLEAN NOT NULL DEFAULT 0, -- should this contact receive serial claims
3007 acqprimary BOOLEAN NOT NULL DEFAULT 0, -- is this the primary contact for acquisitions messages
3008 serialsprimary BOOLEAN NOT NULL DEFAULT 0, -- is this the primary contact for serials messages
3009 booksellerid int(11) not NULL,
3011 CONSTRAINT booksellerid_aqcontacts_fk FOREIGN KEY (booksellerid)
3012 REFERENCES aqbooksellers (id) ON DELETE CASCADE ON UPDATE CASCADE
3013 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci AUTO_INCREMENT=1;
3016 -- Table structure for table 'aqcontract'
3019 DROP TABLE IF EXISTS `aqcontract`;
3020 CREATE TABLE `aqcontract` (
3021 `contractnumber` int(11) NOT NULL auto_increment,
3022 `contractstartdate` date default NULL,
3023 `contractenddate` date default NULL,
3024 `contractname` varchar(50) default NULL,
3025 `contractdescription` mediumtext,
3026 `booksellerid` int(11) not NULL,
3027 PRIMARY KEY (`contractnumber`),
3028 CONSTRAINT `booksellerid_fk1` FOREIGN KEY (`booksellerid`)
3029 REFERENCES `aqbooksellers` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
3030 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci AUTO_INCREMENT=1 ;
3033 -- Table structure for table `aqorders`
3036 DROP TABLE IF EXISTS `aqorders`;
3037 CREATE TABLE `aqorders` ( -- information related to the basket line items
3038 `ordernumber` int(11) NOT NULL auto_increment, -- primary key and unique identifier assigned by Koha to each line
3039 `biblionumber` int(11) default NULL, -- links the order to the biblio being ordered (biblio.biblionumber)
3040 `entrydate` date default NULL, -- the date the bib was added to the basket
3041 `quantity` smallint(6) default NULL, -- the quantity ordered
3042 `currency` varchar(3) default NULL, -- the currency used for the purchase
3043 `listprice` decimal(28,6) default NULL, -- the vendor price for this line item
3044 `datereceived` date default NULL, -- the date this order was received
3045 invoiceid int(11) default NULL, -- id of invoice
3046 `freight` decimal(28,6) default NULL, -- shipping costs (not used)
3047 `unitprice` decimal(28,6) default NULL, -- the actual cost entered when receiving this line item
3048 `quantityreceived` smallint(6) NOT NULL default 0, -- the quantity that have been received so far
3049 `datecancellationprinted` date default NULL, -- the date the line item was deleted
3050 `cancellationreason` text default NULL, -- reason of cancellation
3051 `order_internalnote` mediumtext, -- notes related to this order line, made for staff
3052 `order_vendornote` mediumtext, -- notes related to this order line, made for vendor
3053 `purchaseordernumber` mediumtext, -- not used? always NULL
3054 `basketno` int(11) default NULL, -- links this order line to a specific basket (aqbasket.basketno)
3055 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- the date and time this order line was last modified
3056 `rrp` decimal(13,2) default NULL, -- the replacement cost for this line item
3057 `ecost` decimal(13,2) default NULL, -- the estimated cost for this line item
3058 `gstrate` decimal(6,4) default NULL, -- the tax rate for this line item
3059 `discount` float(6,4) default NULL, -- the discount for this line item
3060 `budget_id` int(11) NOT NULL, -- the fund this order goes against (aqbudgets.budget_id)
3061 `budgetgroup_id` int(11) NOT NULL, -- not used? always zero
3062 `budgetdate` date default NULL, -- not used? always NULL
3063 `sort1` varchar(80) default NULL, -- statistical field
3064 `sort2` varchar(80) default NULL, -- second statistical field
3065 `sort1_authcat` varchar(10) default NULL,
3066 `sort2_authcat` varchar(10) default NULL,
3067 `uncertainprice` tinyint(1), -- was this price uncertain (1 for yes, 0 for no)
3068 `claims_count` int(11) default 0, -- count of claim letters generated
3069 `claimed_date` date default NULL, -- last date a claim was generated
3070 `subscriptionid` int(11) default NULL, -- links this order line to a subscription (subscription.subscriptionid)
3071 parent_ordernumber int(11) default NULL, -- ordernumber of parent order line, or same as ordernumber if no parent
3072 `orderstatus` varchar(16) default 'new', -- the current status for this line item. Can be 'new', 'ordered', 'partial', 'complete' or 'cancelled'
3073 PRIMARY KEY (`ordernumber`),
3074 KEY `basketno` (`basketno`),
3075 KEY `biblionumber` (`biblionumber`),
3076 KEY `budget_id` (`budget_id`),
3077 CONSTRAINT `aqorders_budget_id_fk` FOREIGN KEY (`budget_id`) REFERENCES `aqbudgets` (`budget_id`) ON DELETE CASCADE ON UPDATE CASCADE,
3078 CONSTRAINT `aqorders_ibfk_1` FOREIGN KEY (`basketno`) REFERENCES `aqbasket` (`basketno`) ON DELETE CASCADE ON UPDATE CASCADE,
3079 CONSTRAINT `aqorders_ibfk_2` FOREIGN KEY (`biblionumber`) REFERENCES `biblio` (`biblionumber`) ON DELETE SET NULL ON UPDATE CASCADE,
3080 CONSTRAINT aqorders_ibfk_3 FOREIGN KEY (invoiceid) REFERENCES aqinvoices (invoiceid) ON DELETE SET NULL ON UPDATE CASCADE,
3081 CONSTRAINT `aqorders_subscriptionid` FOREIGN KEY (`subscriptionid`) REFERENCES `subscription` (`subscriptionid`) ON DELETE CASCADE ON UPDATE CASCADE
3082 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3085 -- Table structure for table `aqorder_users`
3088 DROP TABLE IF EXISTS `aqorder_users`;
3089 CREATE TABLE aqorder_users ( -- Mapping orders to patrons for notification sending
3090 ordernumber int(11) NOT NULL, -- the order this patrons receive notifications from (aqorders.ordernumber)
3091 borrowernumber int(11) NOT NULL, -- the borrowernumber for the patron receiving notifications for this order (borrowers.borrowernumber)
3092 PRIMARY KEY (ordernumber, borrowernumber),
3093 CONSTRAINT aqorder_users_ibfk_1 FOREIGN KEY (ordernumber) REFERENCES aqorders (ordernumber) ON DELETE CASCADE ON UPDATE CASCADE,
3094 CONSTRAINT aqorder_users_ibfk_2 FOREIGN KEY (borrowernumber) REFERENCES borrowers (borrowernumber) ON DELETE CASCADE ON UPDATE CASCADE
3095 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3098 -- Table structure for table `aqorders_items`
3101 DROP TABLE IF EXISTS `aqorders_items`;
3102 CREATE TABLE `aqorders_items` ( -- information on items entered in the acquisitions process
3103 `ordernumber` int(11) NOT NULL, -- the order this item is attached to (aqorders.ordernumber)
3104 `itemnumber` int(11) NOT NULL, -- the item number for this item (items.itemnumber)
3105 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- the date and time this order item was last touched
3106 PRIMARY KEY (`itemnumber`),
3107 KEY `ordernumber` (`ordernumber`),
3108 CONSTRAINT aqorders_items_ibfk_1 FOREIGN KEY (ordernumber) REFERENCES aqorders (ordernumber) ON DELETE CASCADE ON UPDATE CASCADE
3109 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3113 -- Table structure for table aqorders_transfers
3116 DROP TABLE IF EXISTS aqorders_transfers;
3117 CREATE TABLE aqorders_transfers (
3118 ordernumber_from int(11) NULL,
3119 ordernumber_to int(11) NULL,
3120 timestamp timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
3121 UNIQUE KEY ordernumber_from (ordernumber_from),
3122 UNIQUE KEY ordernumber_to (ordernumber_to),
3123 CONSTRAINT aqorders_transfers_ordernumber_from FOREIGN KEY (ordernumber_from) REFERENCES aqorders (ordernumber) ON DELETE SET NULL ON UPDATE CASCADE,
3124 CONSTRAINT aqorders_transfers_ordernumber_to FOREIGN KEY (ordernumber_to) REFERENCES aqorders (ordernumber) ON DELETE SET NULL ON UPDATE CASCADE
3125 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3128 -- Table structure for table aqinvoices
3131 DROP TABLE IF EXISTS aqinvoices;
3132 CREATE TABLE aqinvoices (
3133 invoiceid int(11) NOT NULL AUTO_INCREMENT, -- ID of the invoice, primary key
3134 invoicenumber mediumtext NOT NULL, -- Name of invoice
3135 booksellerid int(11) NOT NULL, -- foreign key to aqbooksellers
3136 shipmentdate date default NULL, -- date of shipment
3137 billingdate date default NULL, -- date of billing
3138 closedate date default NULL, -- invoice close date, NULL means the invoice is open
3139 shipmentcost decimal(28,6) default NULL, -- shipment cost
3140 shipmentcost_budgetid int(11) default NULL, -- foreign key to aqbudgets, link the shipment cost to a budget
3141 PRIMARY KEY (invoiceid),
3142 CONSTRAINT aqinvoices_fk_aqbooksellerid FOREIGN KEY (booksellerid) REFERENCES aqbooksellers (id) ON DELETE CASCADE ON UPDATE CASCADE,
3143 CONSTRAINT aqinvoices_fk_shipmentcost_budgetid FOREIGN KEY (shipmentcost_budgetid) REFERENCES aqbudgets (budget_id) ON DELETE SET NULL ON UPDATE CASCADE
3144 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3148 -- Table structure for table `fieldmapping`
3151 DROP TABLE IF EXISTS `fieldmapping`;
3152 CREATE TABLE `fieldmapping` ( -- koha to keyword mapping
3153 `id` int(11) NOT NULL auto_increment, -- unique identifier assigned by Koha
3154 `field` varchar(255) NOT NULL, -- keyword to be mapped to (ex. subtitle)
3155 `frameworkcode` char(4) NOT NULL default '', -- foreign key from the biblio_framework table to link this mapping to a specific framework
3156 `fieldcode` char(3) NOT NULL, -- marc field number to map to this keyword
3157 `subfieldcode` char(1) NOT NULL, -- marc subfield associated with the fieldcode to map to this keyword
3159 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3162 -- Table structure for table `transport_cost`
3165 DROP TABLE IF EXISTS transport_cost;
3166 CREATE TABLE transport_cost (
3167 frombranch varchar(10) NOT NULL,
3168 tobranch varchar(10) NOT NULL,
3169 cost decimal(6,2) NOT NULL,
3170 disable_transfer tinyint(1) NOT NULL DEFAULT 0,
3171 CHECK ( frombranch <> tobranch ), -- a dud check, mysql does not support that
3172 PRIMARY KEY (frombranch, tobranch),
3173 CONSTRAINT transport_cost_ibfk_1 FOREIGN KEY (frombranch) REFERENCES branches (branchcode) ON DELETE CASCADE ON UPDATE CASCADE,
3174 CONSTRAINT transport_cost_ibfk_2 FOREIGN KEY (tobranch) REFERENCES branches (`branchcode`) ON DELETE CASCADE ON UPDATE CASCADE
3175 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3178 -- Table structure for table `biblioimages`
3181 DROP TABLE IF EXISTS `biblioimages`;
3183 CREATE TABLE `biblioimages` ( -- local cover images
3184 `imagenumber` int(11) NOT NULL AUTO_INCREMENT, -- unique identifier for the image
3185 `biblionumber` int(11) NOT NULL, -- foreign key from biblio table to link to biblionumber
3186 `mimetype` varchar(15) NOT NULL, -- image type
3187 `imagefile` mediumblob NOT NULL, -- image file contents
3188 `thumbnail` mediumblob NOT NULL, -- thumbnail file contents
3189 PRIMARY KEY (`imagenumber`),
3190 CONSTRAINT `bibliocoverimage_fk1` FOREIGN KEY (`biblionumber`) REFERENCES `biblio` (`biblionumber`) ON DELETE CASCADE ON UPDATE CASCADE
3191 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3194 -- Table structure for table `social_data`
3197 DROP TABLE IF EXISTS `social_data`;
3198 CREATE TABLE IF NOT EXISTS `social_data` (
3201 `num_critics_pro` INT,
3202 `num_quotations` INT,
3204 `score_avg` DECIMAL(5,2),
3206 PRIMARY KEY (`isbn`)
3207 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3210 -- 'Ratings' table. This tracks the star ratings set by borrowers.
3213 DROP TABLE IF EXISTS ratings;
3214 CREATE TABLE ratings ( -- information related to the star ratings in the OPAC
3215 borrowernumber int(11) NOT NULL, -- the borrowernumber of the patron who left this rating (borrowers.borrowernumber)
3216 biblionumber int(11) NOT NULL, -- the biblio this rating is for (biblio.biblionumber)
3217 rating_value tinyint(1) NOT NULL, -- the rating, from 1 to 5
3218 timestamp timestamp NOT NULL default CURRENT_TIMESTAMP,
3219 PRIMARY KEY (borrowernumber,biblionumber),
3220 CONSTRAINT ratings_ibfk_1 FOREIGN KEY (borrowernumber) REFERENCES borrowers (borrowernumber) ON DELETE CASCADE ON UPDATE CASCADE,
3221 CONSTRAINT ratings_ibfk_2 FOREIGN KEY (biblionumber) REFERENCES biblio (biblionumber) ON DELETE CASCADE ON UPDATE CASCADE
3222 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3225 -- Table structure for table `quotes`
3228 DROP TABLE IF EXISTS quotes;
3229 CREATE TABLE `quotes` ( -- data for the quote of the day feature
3230 `id` int(11) NOT NULL AUTO_INCREMENT, -- unique id for the quote
3231 `source` text DEFAULT NULL, -- source/credit for the quote
3232 `text` mediumtext NOT NULL, -- text of the quote
3233 `timestamp` datetime NOT NULL, -- date and time that the quote last appeared in the opac
3235 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3238 -- Table structure for table categories_branches
3241 DROP TABLE IF EXISTS categories_branches;
3242 CREATE TABLE categories_branches( -- association table between categories and branches
3243 categorycode VARCHAR(10),
3244 branchcode VARCHAR(10),
3245 FOREIGN KEY (categorycode) REFERENCES categories(categorycode) ON DELETE CASCADE,
3246 FOREIGN KEY (branchcode) REFERENCES branches(branchcode) ON DELETE CASCADE
3247 ) ENGINE=INNODB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3250 -- Table structure for table authorised_values_branches
3253 DROP TABLE IF EXISTS authorised_values_branches;
3254 CREATE TABLE authorised_values_branches( -- association table between authorised_values and branches
3256 branchcode VARCHAR(10),
3257 FOREIGN KEY (av_id) REFERENCES authorised_values(id) ON DELETE CASCADE,
3258 FOREIGN KEY (branchcode) REFERENCES branches(branchcode) ON DELETE CASCADE
3259 ) ENGINE=INNODB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3263 -- Table structure for table borrower_attribute_types_branches
3266 DROP TABLE IF EXISTS borrower_attribute_types_branches;
3267 CREATE TABLE borrower_attribute_types_branches( -- association table between borrower_attribute_types and branches
3268 bat_code VARCHAR(10),
3269 b_branchcode VARCHAR(10),
3270 FOREIGN KEY (bat_code) REFERENCES borrower_attribute_types(code) ON DELETE CASCADE,
3271 FOREIGN KEY (b_branchcode) REFERENCES branches(branchcode) ON DELETE CASCADE
3272 ) ENGINE=INNODB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3275 -- Table structure for table `borrower_modifications`
3278 CREATE TABLE IF NOT EXISTS `borrower_modifications` (
3279 `timestamp` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
3280 `verification_token` varchar(255) NOT NULL DEFAULT '',
3281 `borrowernumber` int(11) NOT NULL DEFAULT '0',
3282 `cardnumber` varchar(16) DEFAULT NULL,
3283 `surname` mediumtext,
3286 `othernames` mediumtext,
3288 `streetnumber` varchar(10) DEFAULT NULL,
3289 `streettype` varchar(50) DEFAULT NULL,
3290 `address` mediumtext,
3294 `zipcode` varchar(25) DEFAULT NULL,
3298 `mobile` varchar(50) DEFAULT NULL,
3302 `B_streetnumber` varchar(10) DEFAULT NULL,
3303 `B_streettype` varchar(50) DEFAULT NULL,
3304 `B_address` varchar(100) DEFAULT NULL,
3306 `B_city` mediumtext,
3308 `B_zipcode` varchar(25) DEFAULT NULL,
3311 `B_phone` mediumtext,
3312 `dateofbirth` date DEFAULT NULL,
3313 `branchcode` varchar(10) DEFAULT NULL,
3314 `categorycode` varchar(10) DEFAULT NULL,
3315 `dateenrolled` date DEFAULT NULL,
3316 `dateexpiry` date DEFAULT NULL,
3317 `gonenoaddress` tinyint(1) DEFAULT NULL,
3318 `lost` tinyint(1) DEFAULT NULL,
3319 `debarred` date DEFAULT NULL,
3320 `debarredcomment` varchar(255) DEFAULT NULL,
3321 `contactname` mediumtext,
3322 `contactfirstname` text,
3323 `contacttitle` text,
3324 `guarantorid` int(11) DEFAULT NULL,
3325 `borrowernotes` mediumtext,
3326 `relationship` varchar(100) DEFAULT NULL,
3327 `ethnicity` varchar(50) DEFAULT NULL,
3328 `ethnotes` varchar(255) DEFAULT NULL,
3329 `sex` varchar(1) DEFAULT NULL,
3330 `password` varchar(30) DEFAULT NULL,
3331 `flags` int(11) DEFAULT NULL,
3332 `userid` varchar(75) DEFAULT NULL,
3333 `opacnote` mediumtext,
3334 `contactnote` varchar(255) DEFAULT NULL,
3335 `sort1` varchar(80) DEFAULT NULL,
3336 `sort2` varchar(80) DEFAULT NULL,
3337 `altcontactfirstname` varchar(255) DEFAULT NULL,
3338 `altcontactsurname` varchar(255) DEFAULT NULL,
3339 `altcontactaddress1` varchar(255) DEFAULT NULL,
3340 `altcontactaddress2` varchar(255) DEFAULT NULL,
3341 `altcontactaddress3` varchar(255) DEFAULT NULL,
3342 `altcontactstate` text,
3343 `altcontactzipcode` varchar(50) DEFAULT NULL,
3344 `altcontactcountry` text,
3345 `altcontactphone` varchar(50) DEFAULT NULL,
3346 `smsalertnumber` varchar(50) DEFAULT NULL,
3347 `privacy` int(11) DEFAULT NULL,
3348 PRIMARY KEY (`verification_token`,`borrowernumber`),
3349 KEY `verification_token` (`verification_token`),
3350 KEY `borrowernumber` (`borrowernumber`)
3351 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3354 -- Table structure for table linktracker
3355 -- This stores clicks to external links
3358 DROP TABLE IF EXISTS linktracker;
3359 CREATE TABLE linktracker (
3360 id int(11) NOT NULL AUTO_INCREMENT, -- primary key identifier
3361 biblionumber int(11) DEFAULT NULL, -- biblionumber of the record the link is from
3362 itemnumber int(11) DEFAULT NULL, -- itemnumber if applicable that the link was from
3363 borrowernumber int(11) DEFAULT NULL, -- borrowernumber who clicked the link
3364 url text, -- the link itself
3365 timeclicked datetime DEFAULT NULL, -- the date and time the link was clicked
3367 KEY bibidx (biblionumber),
3368 KEY itemidx (itemnumber),
3369 KEY borridx (borrowernumber),
3370 KEY dateidx (timeclicked)
3371 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3374 -- Table structure for table 'plugin_data'
3377 CREATE TABLE IF NOT EXISTS plugin_data (
3378 plugin_class varchar(255) NOT NULL,
3379 plugin_key varchar(255) NOT NULL,
3381 PRIMARY KEY (plugin_class,plugin_key)
3382 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3385 -- Table structure for table `patron_lists`
3388 DROP TABLE IF EXISTS patron_lists;
3389 CREATE TABLE patron_lists (
3390 patron_list_id int(11) NOT NULL AUTO_INCREMENT, -- unique identifier
3391 name varchar(255) CHARACTER SET utf8 NOT NULL, -- the list's name
3392 owner int(11) NOT NULL, -- borrowernumber of the list creator
3393 PRIMARY KEY (patron_list_id),
3395 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3398 -- Constraints for table `patron_lists`
3400 ALTER TABLE `patron_lists`
3401 ADD CONSTRAINT patron_lists_ibfk_1 FOREIGN KEY (`owner`) REFERENCES borrowers (borrowernumber) ON DELETE CASCADE ON UPDATE CASCADE;
3404 -- Table structure for table 'patron_list_patrons'
3407 DROP TABLE IF EXISTS patron_list_patrons;
3408 CREATE TABLE patron_list_patrons (
3409 patron_list_patron_id int(11) NOT NULL AUTO_INCREMENT, -- unique identifier
3410 patron_list_id int(11) NOT NULL, -- the list this entry is part of
3411 borrowernumber int(11) NOT NULL, -- the borrower that is part of this list
3412 PRIMARY KEY (patron_list_patron_id),
3413 KEY patron_list_id (patron_list_id),
3414 KEY borrowernumber (borrowernumber)
3415 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3418 -- Constraints for table `patron_list_patrons`
3420 ALTER TABLE `patron_list_patrons`
3421 ADD CONSTRAINT patron_list_patrons_ibfk_1 FOREIGN KEY (patron_list_id) REFERENCES patron_lists (patron_list_id) ON DELETE CASCADE ON UPDATE CASCADE,
3422 ADD CONSTRAINT patron_list_patrons_ibfk_2 FOREIGN KEY (borrowernumber) REFERENCES borrowers (borrowernumber) ON DELETE CASCADE ON UPDATE CASCADE;
3425 -- Table structure for table 'marc_modification_templates'
3428 CREATE TABLE IF NOT EXISTS marc_modification_templates (
3429 template_id int(11) NOT NULL AUTO_INCREMENT,
3431 PRIMARY KEY (template_id)
3432 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3435 -- Table structure for table 'marc_modification_template_actions'
3438 CREATE TABLE IF NOT EXISTS marc_modification_template_actions (
3439 mmta_id int(11) NOT NULL AUTO_INCREMENT,
3440 template_id int(11) NOT NULL,
3441 ordering int(3) NOT NULL,
3442 action enum('delete_field','update_field','move_field','copy_field') NOT NULL,
3443 field_number smallint(6) NOT NULL DEFAULT '0',
3444 from_field varchar(3) NOT NULL,
3445 from_subfield varchar(1) DEFAULT NULL,
3446 field_value varchar(100) DEFAULT NULL,
3447 to_field varchar(3) DEFAULT NULL,
3448 to_subfield varchar(1) DEFAULT NULL,
3449 to_regex_search text,
3450 to_regex_replace text,
3451 to_regex_modifiers varchar(8) DEFAULT '',
3452 conditional enum('if','unless') DEFAULT NULL,
3453 conditional_field varchar(3) DEFAULT NULL,
3454 conditional_subfield varchar(1) DEFAULT NULL,
3455 conditional_comparison enum('exists','not_exists','equals','not_equals') DEFAULT NULL,
3456 conditional_value text,
3457 conditional_regex tinyint(1) NOT NULL DEFAULT '0',
3459 PRIMARY KEY (mmta_id),
3460 CONSTRAINT `mmta_ibfk_1` FOREIGN KEY (`template_id`) REFERENCES `marc_modification_templates` (`template_id`) ON DELETE CASCADE ON UPDATE CASCADE
3461 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3464 -- Table structure for table `misc_files`
3467 CREATE TABLE IF NOT EXISTS `misc_files` ( -- miscellaneous files attached to records from various tables
3468 `file_id` int(11) NOT NULL AUTO_INCREMENT, -- unique id for the file record
3469 `table_tag` varchar(255) NOT NULL, -- usually table name, or arbitrary unique tag
3470 `record_id` int(11) NOT NULL, -- record id from the table this file is associated to
3471 `file_name` varchar(255) NOT NULL, -- file name
3472 `file_type` varchar(255) NOT NULL, -- MIME type of the file
3473 `file_description` varchar(255) DEFAULT NULL, -- description given to the file
3474 `file_content` longblob NOT NULL, -- file content
3475 `date_uploaded` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, -- date and time the file was added
3476 PRIMARY KEY (`file_id`),
3477 KEY `table_tag` (`table_tag`),
3478 KEY `record_id` (`record_id`)
3479 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3482 -- Table structure for table `columns_settings`
3485 CREATE TABLE IF NOT EXISTS columns_settings (
3486 module varchar(255) NOT NULL,
3487 page varchar(255) NOT NULL,
3488 tablename varchar(255) NOT NULL,
3489 columnname varchar(255) NOT NULL,
3490 cannot_be_toggled int(1) NOT NULL DEFAULT 0,
3491 is_hidden int(1) NOT NULL DEFAULT 0,
3492 PRIMARY KEY(module, page, tablename, columnname)
3493 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3496 -- Table structure for table 'items_search_fields'
3499 DROP TABLE IF EXISTS items_search_fields;
3500 CREATE TABLE items_search_fields (
3501 name VARCHAR(255) NOT NULL,
3502 label VARCHAR(255) NOT NULL,
3503 tagfield CHAR(3) NOT NULL,
3504 tagsubfield CHAR(1) NULL DEFAULT NULL,
3505 authorised_values_category VARCHAR(32) NULL DEFAULT NULL,
3507 CONSTRAINT items_search_fields_authorised_values_category
3508 FOREIGN KEY (authorised_values_category) REFERENCES authorised_values (category)
3509 ON DELETE SET NULL ON UPDATE CASCADE
3510 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3513 -- Table structure for table 'discharges'
3516 DROP TABLE IF EXISTS discharges;
3517 CREATE TABLE discharges (
3518 borrower int(11) DEFAULT NULL,
3519 needed timestamp NULL DEFAULT NULL,
3520 validated timestamp NULL DEFAULT NULL,
3521 KEY borrower_discharges_ibfk1 (borrower),
3522 CONSTRAINT borrower_discharges_ibfk1 FOREIGN KEY (borrower) REFERENCES borrowers (borrowernumber) ON DELETE CASCADE ON UPDATE CASCADE
3523 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3525 /*!40103 SET TIME_ZONE=@OLD_TIME_ZONE */;
3526 /*!40101 SET SQL_MODE=@OLD_SQL_MODE */;
3527 /*!40014 SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS */;
3528 /*!40014 SET UNIQUE_CHECKS=@OLD_UNIQUE_CHECKS */;
3529 /*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */;
3530 /*!40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */;
3531 /*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */;
3532 /*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */;