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/borrower'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 `sex` varchar(1) default NULL, -- patron/borrower's gender
249 `password` varchar(60) default NULL, -- patron/borrower's encrypted password
250 `flags` int(11) default NULL, -- will include a number associated with the staff member's permissions
251 `userid` varchar(75) default NULL, -- patron/borrower's opac and/or staff client log in
252 `opacnote` mediumtext, -- a note on the patron/borrower's account that is visible in the OPAC and staff client
253 `contactnote` varchar(255) default NULL, -- a note related to the patron/borrower's alternate address
254 `sort1` varchar(80) default NULL, -- a field that can be used for any information unique to the library
255 `sort2` varchar(80) default NULL, -- a field that can be used for any information unique to the library
256 `altcontactfirstname` varchar(255) default NULL, -- first name of alternate contact for the patron/borrower
257 `altcontactsurname` varchar(255) default NULL, -- surname or last name of the alternate contact for the patron/borrower
258 `altcontactaddress1` varchar(255) default NULL, -- the first address line for the alternate contact for the patron/borrower
259 `altcontactaddress2` varchar(255) default NULL, -- the second address line for the alternate contact for the patron/borrower
260 `altcontactaddress3` varchar(255) default NULL, -- the city for the alternate contact for the patron/borrower
261 `altcontactstate` text default NULL, -- the state for the alternate contact for the patron/borrower
262 `altcontactzipcode` varchar(50) default NULL, -- the zipcode for the alternate contact for the patron/borrower
263 `altcontactcountry` text default NULL, -- the country for the alternate contact for the patron/borrower
264 `altcontactphone` varchar(50) default NULL, -- the phone number for the alternate contact for the patron/borrower
265 `smsalertnumber` varchar(50) default NULL, -- the mobile phone number where the patron/borrower would like to receive notices (if SNS turned on)
266 `privacy` integer(11) DEFAULT '1' NOT NULL, -- patron/borrower's privacy settings related to their reading history
267 UNIQUE KEY `cardnumber` (`cardnumber`),
268 PRIMARY KEY `borrowernumber` (`borrowernumber`),
269 KEY `categorycode` (`categorycode`),
270 KEY `branchcode` (`branchcode`),
271 UNIQUE KEY `userid` (`userid`),
272 KEY `guarantorid` (`guarantorid`),
273 KEY `surname_idx` (`surname`(255)),
274 KEY `firstname_idx` (`firstname`(255)),
275 KEY `othernames_idx` (`othernames`(255)),
276 CONSTRAINT `borrowers_ibfk_1` FOREIGN KEY (`categorycode`) REFERENCES `categories` (`categorycode`),
277 CONSTRAINT `borrowers_ibfk_2` FOREIGN KEY (`branchcode`) REFERENCES `branches` (`branchcode`)
278 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
281 -- Table structure for table `borrower_attribute_types`
284 DROP TABLE IF EXISTS `borrower_attribute_types`;
285 CREATE TABLE `borrower_attribute_types` ( -- definitions for custom patron fields known as extended patron attributes
286 `code` varchar(10) NOT NULL, -- unique key used to identify each custom field
287 `description` varchar(255) NOT NULL, -- description for each custom field
288 `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)
289 `unique_id` tinyint(1) NOT NULL default 0, -- defines if this value needs to be unique (1 for yes, 0 for no)
290 `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)
291 `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)
292 `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)
293 `authorised_value_category` varchar(32) default NULL, -- foreign key from authorised_values that links this custom field to an authorized value category
294 `display_checkout` tinyint(1) NOT NULL default 0,-- defines if this field displays in checkout screens
295 `category_code` VARCHAR(10) NULL DEFAULT NULL,-- defines a category for an attribute_type
296 `class` VARCHAR(255) NOT NULL DEFAULT '',-- defines a class for an attribute_type
297 PRIMARY KEY (`code`),
298 KEY `auth_val_cat_idx` (`authorised_value_category`)
299 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
302 -- Table structure for table `borrower_attributes`
305 DROP TABLE IF EXISTS `borrower_attributes`;
306 CREATE TABLE `borrower_attributes` ( -- values of custom patron fields known as extended patron attributes linked to patrons/borrowers
307 `borrowernumber` int(11) NOT NULL, -- foreign key from the borrowers table, defines which patron/borrower has this attribute
308 `code` varchar(10) NOT NULL, -- foreign key from the borrower_attribute_types table, defines which custom field this value was entered for
309 `attribute` varchar(255) default NULL, -- custom patron field value
310 `password` varchar(64) default NULL, -- password associated with this field
311 KEY `borrowernumber` (`borrowernumber`),
312 KEY `code_attribute` (`code`, `attribute`),
313 CONSTRAINT `borrower_attributes_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`)
314 ON DELETE CASCADE ON UPDATE CASCADE,
315 CONSTRAINT `borrower_attributes_ibfk_2` FOREIGN KEY (`code`) REFERENCES `borrower_attribute_types` (`code`)
316 ON DELETE CASCADE ON UPDATE CASCADE
317 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
320 -- Table structure for table `borrower_debarments`
323 DROP TABLE IF EXISTS `borrower_debarments`;
324 CREATE TABLE borrower_debarments ( -- tracks restrictions on the patron's record
325 borrower_debarment_id int(11) NOT NULL AUTO_INCREMENT, -- unique key for the restriction
326 borrowernumber int(11) NOT NULL, -- foreign key for borrowers.borrowernumber for patron who is restricted
327 expiration date DEFAULT NULL, -- expiration date of the restriction
328 `type` enum('SUSPENSION','OVERDUES','MANUAL','DISCHARGE') NOT NULL DEFAULT 'MANUAL', -- type of restriction
329 `comment` text, -- comments about the restriction
330 manager_id int(11) DEFAULT NULL, -- foreign key for borrowers.borrowernumber for the librarian managing the restriction
331 created timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, -- date the restriction was added
332 updated timestamp NULL DEFAULT NULL, -- date the restriction was updated
333 PRIMARY KEY (borrower_debarment_id),
334 KEY borrowernumber (borrowernumber),
335 CONSTRAINT `borrower_debarments_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`)
336 ON DELETE CASCADE ON UPDATE CASCADE
337 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
341 -- Table structure for table `branch_item_rules`
344 DROP TABLE IF EXISTS `branch_item_rules`;
345 CREATE TABLE `branch_item_rules` ( -- information entered in the circulation and fine rules under 'Holds policy by item type'
346 `branchcode` varchar(10) NOT NULL, -- the branch this rule is for (branches.branchcode)
347 `itemtype` varchar(10) NOT NULL, -- the item type this rule applies to (items.itype)
348 `holdallowed` tinyint(1) default NULL, -- the number of holds allowed
349 `returnbranch` varchar(15) default NULL, -- the branch the item returns to (homebranch, holdingbranch, noreturn)
350 PRIMARY KEY (`itemtype`,`branchcode`),
351 KEY `branch_item_rules_ibfk_2` (`branchcode`),
352 CONSTRAINT `branch_item_rules_ibfk_1` FOREIGN KEY (`itemtype`) REFERENCES `itemtypes` (`itemtype`)
353 ON DELETE CASCADE ON UPDATE CASCADE,
354 CONSTRAINT `branch_item_rules_ibfk_2` FOREIGN KEY (`branchcode`) REFERENCES `branches` (`branchcode`)
355 ON DELETE CASCADE ON UPDATE CASCADE
356 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
359 -- Table structure for table borrower_sync
362 DROP TABLE IF EXISTS `borrower_sync`;
363 CREATE TABLE borrower_sync (
364 borrowersyncid int(11) NOT NULL AUTO_INCREMENT, -- Primary key, unique identifier
365 borrowernumber int(11) NOT NULL, -- Connects data about synchronisations to a borrower
366 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
367 sync tinyint(1) NOT NULL DEFAULT '0', -- A boolean (1/0) for turning syncing off and on for individual borrowers
368 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.
369 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.
370 hashed_pin varchar(64) DEFAULT NULL, -- Perhaps specific to The Norwegian national patron database, this column holds a hashed PIN code
371 PRIMARY KEY (borrowersyncid),
372 KEY borrowernumber (borrowernumber),
373 CONSTRAINT borrower_sync_ibfk_1 FOREIGN KEY (borrowernumber) REFERENCES borrowers (borrowernumber) ON DELETE CASCADE ON UPDATE CASCADE
374 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
378 -- Table structure for table `branchcategories`
381 DROP TABLE IF EXISTS `branchcategories`;
382 CREATE TABLE `branchcategories` ( -- information related to library/branch groups
383 `categorycode` varchar(10) NOT NULL default '', -- unique identifier for the library/branch group
384 `categoryname` varchar(32), -- name of the library/branch group
385 `codedescription` mediumtext, -- longer description of the library/branch group
386 `categorytype` varchar(16), -- says whether this is a search group or a properties group
387 `show_in_pulldown` tinyint(1) NOT NULL DEFAULT '0', -- says this group should be in the opac libararies pulldown if it is enabled
388 PRIMARY KEY (`categorycode`),
389 KEY `show_in_pulldown` (`show_in_pulldown`)
390 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
393 -- Table structure for table `branches`
396 DROP TABLE IF EXISTS `branches`;
397 CREATE TABLE `branches` ( -- information about your libraries or branches are stored here
398 `branchcode` varchar(10) NOT NULL default '', -- a unique key assigned to each branch
399 `branchname` mediumtext NOT NULL, -- the name of your library or branch
400 `branchaddress1` mediumtext, -- the first address line of for your library or branch
401 `branchaddress2` mediumtext, -- the second address line of for your library or branch
402 `branchaddress3` mediumtext, -- the third address line of for your library or branch
403 `branchzip` varchar(25) default NULL, -- the zip or postal code for your library or branch
404 `branchcity` mediumtext, -- the city or province for your library or branch
405 `branchstate` mediumtext, -- the state for your library or branch
406 `branchcountry` text, -- the county for your library or branch
407 `branchphone` mediumtext, -- the primary phone for your library or branch
408 `branchfax` mediumtext, -- the fax number for your library or branch
409 `branchemail` mediumtext, -- the primary email address for your library or branch
410 `branchreplyto` mediumtext, -- the email to be used as a Reply-To
411 `branchreturnpath` mediumtext, -- the email to be used as Return-Path
412 `branchurl` mediumtext, -- the URL for your library or branch's website
413 `issuing` tinyint(4) default NULL, -- unused in Koha
414 `branchip` varchar(15) default NULL, -- the IP address for your library or branch
415 `branchprinter` varchar(100) default NULL, -- unused in Koha
416 `branchnotes` mediumtext, -- notes related to your library or branch
417 opac_info text, -- HTML that displays in OPAC
418 PRIMARY KEY (`branchcode`)
419 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
422 -- Table structure for table `branchrelations`
425 DROP TABLE IF EXISTS `branchrelations`;
426 CREATE TABLE `branchrelations` ( -- this table links libraries/branches to groups
427 `branchcode` varchar(10) NOT NULL default '', -- foreign key from the branches table to identify the branch
428 `categorycode` varchar(10) NOT NULL default '', -- foreign key from the branchcategories table to identify the group
429 PRIMARY KEY (`branchcode`,`categorycode`),
430 KEY `branchcode` (`branchcode`),
431 KEY `categorycode` (`categorycode`),
432 CONSTRAINT `branchrelations_ibfk_1` FOREIGN KEY (`branchcode`) REFERENCES `branches` (`branchcode`) ON DELETE CASCADE ON UPDATE CASCADE,
433 CONSTRAINT `branchrelations_ibfk_2` FOREIGN KEY (`categorycode`) REFERENCES `branchcategories` (`categorycode`) ON DELETE CASCADE ON UPDATE CASCADE
434 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
437 -- Table structure for table `branchtransfers`
440 DROP TABLE IF EXISTS `branchtransfers`;
441 CREATE TABLE `branchtransfers` ( -- information for items that are in transit between branches
442 `itemnumber` int(11) NOT NULL default 0, -- the itemnumber that it is in transit (items.itemnumber)
443 `datesent` datetime default NULL, -- the date the transfer was initialized
444 `frombranch` varchar(10) NOT NULL default '', -- the branch the transfer is coming from
445 `datearrived` datetime default NULL, -- the date the transfer arrived at its destination
446 `tobranch` varchar(10) NOT NULL default '', -- the branch the transfer was going to
447 `comments` mediumtext, -- any comments related to the transfer
448 KEY `frombranch` (`frombranch`),
449 KEY `tobranch` (`tobranch`),
450 KEY `itemnumber` (`itemnumber`),
451 CONSTRAINT `branchtransfers_ibfk_1` FOREIGN KEY (`frombranch`) REFERENCES `branches` (`branchcode`) ON DELETE CASCADE ON UPDATE CASCADE,
452 CONSTRAINT `branchtransfers_ibfk_2` FOREIGN KEY (`tobranch`) REFERENCES `branches` (`branchcode`) ON DELETE CASCADE ON UPDATE CASCADE,
453 CONSTRAINT `branchtransfers_ibfk_3` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`) ON DELETE CASCADE ON UPDATE CASCADE
454 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
458 -- Table structure for table `browser`
460 DROP TABLE IF EXISTS `browser`;
461 CREATE TABLE `browser` (
462 `level` int(11) NOT NULL,
463 `classification` varchar(20) NOT NULL,
464 `description` varchar(255) NOT NULL,
465 `number` bigint(20) NOT NULL,
466 `endnode` tinyint(4) NOT NULL
467 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
470 -- Table structure for table `categories`
473 DROP TABLE IF EXISTS `categories`;
474 CREATE TABLE `categories` ( -- this table shows information related to Koha patron categories
475 `categorycode` varchar(10) NOT NULL default '', -- unique primary key used to idenfity the patron category
476 `description` mediumtext, -- description of the patron category
477 `enrolmentperiod` smallint(6) default NULL, -- number of months the patron is enrolled for (will be NULL if enrolmentperioddate is set)
478 `enrolmentperioddate` DATE NULL DEFAULT NULL, -- date the patron is enrolled until (will be NULL if enrolmentperiod is set)
479 `upperagelimit` smallint(6) default NULL, -- age limit for the patron
480 `dateofbirthrequired` tinyint(1) default NULL, -- the minimum age required for the patron category
481 `finetype` varchar(30) default NULL, -- unused in Koha
482 `bulk` tinyint(1) default NULL,
483 `enrolmentfee` decimal(28,6) default NULL, -- enrollment fee for the patron
484 `overduenoticerequired` tinyint(1) default NULL, -- are overdue notices sent to this patron category (1 for yes, 0 for no)
485 `issuelimit` smallint(6) default NULL, -- unused in Koha
486 `reservefee` decimal(28,6) default NULL, -- cost to place holds
487 `hidelostitems` tinyint(1) NOT NULL default '0', -- are lost items shown to this category (1 for yes, 0 for no)
488 `category_type` varchar(1) NOT NULL default 'A', -- type of Koha patron (Adult, Child, Professional, Organizational, Statistical, Staff)
489 `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
490 `default_privacy` ENUM( 'default', 'never', 'forever' ) NOT NULL DEFAULT 'default', -- Default privacy setting for this patron category
491 PRIMARY KEY (`categorycode`),
492 UNIQUE KEY `categorycode` (`categorycode`)
493 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
496 -- Table: collections
498 DROP TABLE IF EXISTS collections;
499 CREATE TABLE collections (
500 colId integer(11) NOT NULL auto_increment,
501 colTitle varchar(100) NOT NULL DEFAULT '',
502 colDesc text NOT NULL,
503 colBranchcode varchar(10) DEFAULT NULL, -- 'branchcode for branch where item should be held.'
505 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
508 -- Constraints for table `collections`
510 ALTER TABLE `collections`
511 ADD CONSTRAINT `collections_ibfk_1` FOREIGN KEY (`colBranchcode`) REFERENCES `branches` (`branchcode`) ON DELETE CASCADE ON UPDATE CASCADE;
514 -- Table: collections_tracking
516 DROP TABLE IF EXISTS collections_tracking;
517 CREATE TABLE collections_tracking (
518 collections_tracking_id integer(11) NOT NULL auto_increment,
519 colId integer(11) NOT NULL DEFAULT 0 comment 'collections.colId',
520 itemnumber integer(11) NOT NULL DEFAULT 0 comment 'items.itemnumber',
521 PRIMARY KEY (collections_tracking_id)
522 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
525 -- Table structure for table `courses`
528 -- The courses table stores the courses created for the
529 -- course reserves feature.
531 DROP TABLE IF EXISTS courses;
532 CREATE TABLE `courses` (
533 `course_id` int(11) NOT NULL AUTO_INCREMENT, -- unique id for the course
534 `department` varchar(80) DEFAULT NULL, -- the authorised value for the DEPARTMENT
535 `course_number` varchar(255) DEFAULT NULL, -- the "course number" assigned to a course
536 `section` varchar(255) DEFAULT NULL, -- the 'section' of a course
537 `course_name` varchar(255) DEFAULT NULL, -- the name of the course
538 `term` varchar(80) DEFAULT NULL, -- the authorised value for the TERM
539 `staff_note` mediumtext, -- the text of the staff only note
540 `public_note` mediumtext, -- the text of the public / opac note
541 `students_count` varchar(20) DEFAULT NULL, -- how many students will be taking this course/section
542 `enabled` enum('yes','no') NOT NULL DEFAULT 'yes', -- determines whether the course is active
543 `timestamp` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
544 PRIMARY KEY (`course_id`)
545 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
548 -- Table structure for table `course_instructors`
551 -- The course instructors table links Koha borrowers to the
552 -- courses they are teaching. Many instructors can teach many
553 -- courses. course_instructors is just a many-to-many join table.
555 DROP TABLE IF EXISTS course_instructors;
556 CREATE TABLE `course_instructors` (
557 `course_id` int(11) NOT NULL, -- foreign key to link to courses.course_id
558 `borrowernumber` int(11) NOT NULL, -- foreign key to link to borrowers.borrowernumber for instructor information
559 PRIMARY KEY (`course_id`,`borrowernumber`),
560 KEY `borrowernumber` (`borrowernumber`)
561 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
564 -- Constraints for table `course_instructors`
566 ALTER TABLE `course_instructors`
567 ADD CONSTRAINT `course_instructors_ibfk_2` FOREIGN KEY (`course_id`) REFERENCES `courses` (`course_id`),
568 ADD CONSTRAINT `course_instructors_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE;
571 -- Table structure for table `course_items`
574 -- If an item is placed on course reserve for one or more courses
575 -- it will have an entry in this table. No matter how many courses an item
576 -- is part of, it will only have one row in this table.
578 DROP TABLE IF EXISTS course_items;
579 CREATE TABLE `course_items` (
580 `ci_id` int(11) NOT NULL AUTO_INCREMENT, -- course item id
581 `itemnumber` int(11) NOT NULL, -- items.itemnumber for the item on reserve
582 `itype` varchar(10) DEFAULT NULL, -- new itemtype for the item to have while on reserve (optional)
583 `ccode` varchar(10) DEFAULT NULL, -- new category code for the item to have while on reserve (optional)
584 `holdingbranch` varchar(10) DEFAULT NULL, -- new holding branch for the item to have while on reserve (optional)
585 `location` varchar(80) DEFAULT NULL, -- new shelving location for the item to have while on reseve (optional)
586 `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'
587 `timestamp` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
588 PRIMARY KEY (`ci_id`),
589 UNIQUE KEY `itemnumber` (`itemnumber`),
590 KEY `holdingbranch` (`holdingbranch`)
591 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
594 -- Constraints for table `course_items`
596 ALTER TABLE `course_items`
597 ADD CONSTRAINT `course_items_ibfk_2` FOREIGN KEY (`holdingbranch`) REFERENCES `branches` (`branchcode`) ON DELETE CASCADE ON UPDATE CASCADE,
598 ADD CONSTRAINT `course_items_ibfk_1` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`) ON DELETE CASCADE ON UPDATE CASCADE;
601 -- Table structure for table `course_reserves`
604 -- This table connects an item placed on course reserve to a course it is on reserve for.
605 -- There will be a row in this table for each course an item is on reserve for.
607 DROP TABLE IF EXISTS course_reserves;
608 CREATE TABLE `course_reserves` (
609 `cr_id` int(11) NOT NULL AUTO_INCREMENT,
610 `course_id` int(11) NOT NULL, -- foreign key to link to courses.course_id
611 `ci_id` int(11) NOT NULL, -- foreign key to link to courses_items.ci_id
612 `staff_note` mediumtext, -- staff only note
613 `public_note` mediumtext, -- public, OPAC visible note
614 `timestamp` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
615 PRIMARY KEY (`cr_id`),
616 UNIQUE KEY `pseudo_key` (`course_id`,`ci_id`),
617 KEY `course_id` (`course_id`)
618 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
621 -- Constraints for table `course_reserves`
623 ALTER TABLE `course_reserves`
624 ADD CONSTRAINT `course_reserves_ibfk_1` FOREIGN KEY (`course_id`) REFERENCES `courses` (`course_id`),
625 ADD CONSTRAINT `course_reserves_ibfk_2` FOREIGN KEY (`ci_id`) REFERENCES `course_items` (`ci_id`) ON DELETE CASCADE ON UPDATE CASCADE;
629 -- Table structure for table `branch_borrower_circ_rules`
632 DROP TABLE IF EXISTS `branch_borrower_circ_rules`;
633 CREATE TABLE `branch_borrower_circ_rules` ( -- includes default circulation rules for patron categories found under "Checkout limit by patron category"
634 `branchcode` VARCHAR(10) NOT NULL, -- the branch this rule applies to (branches.branchcode)
635 `categorycode` VARCHAR(10) NOT NULL, -- the patron category this rule applies to (categories.categorycode)
636 `maxissueqty` int(4) default NULL, -- the maximum number of checkouts this patron category can have at this branch
637 `maxonsiteissueqty` int(4) default NULL, -- the maximum number of on-site checkouts this patron category can have at this branch
638 PRIMARY KEY (`categorycode`, `branchcode`),
639 CONSTRAINT `branch_borrower_circ_rules_ibfk_1` FOREIGN KEY (`categorycode`) REFERENCES `categories` (`categorycode`)
640 ON DELETE CASCADE ON UPDATE CASCADE,
641 CONSTRAINT `branch_borrower_circ_rules_ibfk_2` FOREIGN KEY (`branchcode`) REFERENCES `branches` (`branchcode`)
642 ON DELETE CASCADE ON UPDATE CASCADE
643 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
646 -- Table structure for table `default_borrower_circ_rules`
649 DROP TABLE IF EXISTS `default_borrower_circ_rules`;
650 CREATE TABLE `default_borrower_circ_rules` ( -- default checkout rules found under "Default checkout, hold and return policy"
651 `categorycode` VARCHAR(10) NOT NULL, -- patron category this rul
652 `maxissueqty` int(4) default NULL,
653 `maxonsiteissueqty` int(4) default NULL,
654 PRIMARY KEY (`categorycode`),
655 CONSTRAINT `borrower_borrower_circ_rules_ibfk_1` FOREIGN KEY (`categorycode`) REFERENCES `categories` (`categorycode`)
656 ON DELETE CASCADE ON UPDATE CASCADE
657 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
660 -- Table structure for table `default_branch_circ_rules`
663 DROP TABLE IF EXISTS `default_branch_circ_rules`;
664 CREATE TABLE `default_branch_circ_rules` (
665 `branchcode` VARCHAR(10) NOT NULL,
666 `maxissueqty` int(4) default NULL,
667 `maxonsiteissueqty` int(4) default NULL,
668 `holdallowed` tinyint(1) default NULL,
669 `returnbranch` varchar(15) default NULL,
670 PRIMARY KEY (`branchcode`),
671 CONSTRAINT `default_branch_circ_rules_ibfk_1` FOREIGN KEY (`branchcode`) REFERENCES `branches` (`branchcode`)
672 ON DELETE CASCADE ON UPDATE CASCADE
673 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
676 -- Table structure for table `default_branch_item_rules`
678 DROP TABLE IF EXISTS `default_branch_item_rules`;
679 CREATE TABLE `default_branch_item_rules` (
680 `itemtype` varchar(10) NOT NULL,
681 `holdallowed` tinyint(1) default NULL,
682 `returnbranch` varchar(15) default NULL,
683 PRIMARY KEY (`itemtype`),
684 CONSTRAINT `default_branch_item_rules_ibfk_1` FOREIGN KEY (`itemtype`) REFERENCES `itemtypes` (`itemtype`)
685 ON DELETE CASCADE ON UPDATE CASCADE
686 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
689 -- Table structure for table `default_circ_rules`
692 DROP TABLE IF EXISTS `default_circ_rules`;
693 CREATE TABLE `default_circ_rules` (
694 `singleton` enum('singleton') NOT NULL default 'singleton',
695 `maxissueqty` int(4) default NULL,
696 `maxonsiteissueqty` int(4) default NULL,
697 `holdallowed` int(1) default NULL,
698 `returnbranch` varchar(15) default NULL,
699 PRIMARY KEY (`singleton`)
700 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
703 -- Table structure for table `cities`
706 DROP TABLE IF EXISTS `cities`;
707 CREATE TABLE `cities` ( -- authorized values for cities/states/countries to choose when adding/editing a patron/borrower
708 `cityid` int(11) NOT NULL auto_increment, -- unique identifier added by Koha
709 `city_name` varchar(100) NOT NULL default '', -- name of the city
710 `city_state` VARCHAR( 100 ) NULL DEFAULT NULL, -- name of the state/province
711 `city_country` VARCHAR( 100 ) NULL DEFAULT NULL, -- name of the country
712 `city_zipcode` varchar(20) default NULL, -- zip or postal code
713 PRIMARY KEY (`cityid`)
714 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
717 -- Table structure for table `class_sort_rules`
720 DROP TABLE IF EXISTS `class_sort_rules`;
721 CREATE TABLE `class_sort_rules` (
722 `class_sort_rule` varchar(10) NOT NULL default '',
723 `description` mediumtext,
724 `sort_routine` varchar(30) NOT NULL default '',
725 PRIMARY KEY (`class_sort_rule`),
726 UNIQUE KEY `class_sort_rule_idx` (`class_sort_rule`)
727 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
730 -- Table structure for table `class_sources`
733 DROP TABLE IF EXISTS `class_sources`;
734 CREATE TABLE `class_sources` (
735 `cn_source` varchar(10) NOT NULL default '',
736 `description` mediumtext,
737 `used` tinyint(4) NOT NULL default 0,
738 `class_sort_rule` varchar(10) NOT NULL default '',
739 PRIMARY KEY (`cn_source`),
740 UNIQUE KEY `cn_source_idx` (`cn_source`),
741 KEY `used_idx` (`used`),
742 CONSTRAINT `class_source_ibfk_1` FOREIGN KEY (`class_sort_rule`) REFERENCES `class_sort_rules` (`class_sort_rule`)
743 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
746 -- Table structure for table `currency`
749 DROP TABLE IF EXISTS `currency`;
750 CREATE TABLE `currency` (
751 `currency` varchar(10) NOT NULL default '',
752 `symbol` varchar(5) default NULL,
753 `isocode` varchar(5) default NULL,
754 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
755 `rate` float(15,5) default NULL,
756 `active` tinyint(1) default NULL,
757 PRIMARY KEY (`currency`)
758 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
761 -- Table structure for table `deletedbiblio`
764 DROP TABLE IF EXISTS `deletedbiblio`;
765 CREATE TABLE `deletedbiblio` ( -- stores information about bibliographic records that have been deleted
766 `biblionumber` int(11) NOT NULL auto_increment, -- unique identifier assigned to each bibliographic record
767 `frameworkcode` varchar(4) NOT NULL default '', -- foriegn key from the biblio_framework table to identify which framework was used in cataloging this record
768 `author` mediumtext, -- statement of responsibility from MARC record (100$a in MARC21)
769 `title` mediumtext, -- title (without the subtitle) from the MARC record (245$a in MARC21)
770 `unititle` mediumtext, -- uniform title (without the subtitle) from the MARC record (240$a in MARC21)
771 `notes` mediumtext, -- values from the general notes field in the MARC record (500$a in MARC21) split by bar (|)
772 `serial` tinyint(1) default NULL, -- Boolean indicating whether biblio is for a serial
773 `seriestitle` mediumtext,
774 `copyrightdate` smallint(6) default NULL, -- publication or copyright date from the MARC record
775 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- date and time this record was last touched
776 `datecreated` DATE NOT NULL, -- the date this record was added to Koha
777 `abstract` mediumtext, -- summary from the MARC record (520$a in MARC21)
778 PRIMARY KEY (`biblionumber`),
779 KEY `blbnoidx` (`biblionumber`)
780 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
783 -- Table structure for table `deletedbiblioitems`
786 DROP TABLE IF EXISTS `deletedbiblioitems`;
787 CREATE TABLE `deletedbiblioitems` ( -- information about bibliographic records that have been deleted
788 `biblioitemnumber` int(11) NOT NULL default 0, -- primary key, unique identifier assigned by Koha
789 `biblionumber` int(11) NOT NULL default 0, -- foreign key linking this table to the biblio table
792 `itemtype` varchar(10) default NULL, -- biblio level item type (MARC21 942$c)
793 `isbn` mediumtext default NULL, -- ISBN (MARC21 020$a)
794 `issn` mediumtext default NULL, -- ISSN (MARC21 022$a)
795 `ean` varchar(13) default NULL,
796 `publicationyear` text,
797 `publishercode` varchar(255) default NULL, -- publisher (MARC21 260$b)
798 `volumedate` date default NULL,
799 `volumedesc` text, -- volume information (MARC21 362$a)
800 `collectiontitle` mediumtext default NULL,
801 `collectionissn` text default NULL,
802 `collectionvolume` mediumtext default NULL,
803 `editionstatement` text default NULL,
804 `editionresponsibility` text default NULL,
805 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
806 `illus` varchar(255) default NULL, -- illustrations (MARC21 300$b)
807 `pages` varchar(255) default NULL, -- number of pages (MARC21 300$c)
809 `size` varchar(255) default NULL, -- material size (MARC21 300$c)
810 `place` varchar(255) default NULL, -- publication place (MARC21 260$a)
811 `lccn` varchar(25) default NULL, -- library of congress control number (MARC21 010$a)
812 `marc` longblob, -- full bibliographic MARC record
813 `url` text default NULL, -- url (MARC21 856$u)
814 `cn_source` varchar(10) default NULL, -- classification source (MARC21 942$2)
815 `cn_class` varchar(30) default NULL,
816 `cn_item` varchar(10) default NULL,
817 `cn_suffix` varchar(10) default NULL,
818 `cn_sort` varchar(255) default NULL, -- normalized version of the call number used for sorting
819 `agerestriction` varchar(255) default NULL, -- target audience/age restriction from the bib record (MARC21 521$a)
820 `totalissues` int(10),
821 `marcxml` longtext, -- full bibliographic MARC record in MARCXML
822 PRIMARY KEY (`biblioitemnumber`),
823 KEY `bibinoidx` (`biblioitemnumber`),
824 KEY `bibnoidx` (`biblionumber`),
825 KEY `itemtype_idx` (`itemtype`),
826 KEY `isbn` (`isbn`(255)),
827 KEY `publishercode` (`publishercode`)
828 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
831 -- Table structure for table `deletedborrowers`
834 DROP TABLE IF EXISTS `deletedborrowers`;
835 CREATE TABLE `deletedborrowers` ( -- stores data related to the patrons/borrowers you have deleted
836 `borrowernumber` int(11) NOT NULL default 0, -- primary key, Koha assigned ID number for patrons/borrowers
837 `cardnumber` varchar(16) default NULL, -- unique key, library assigned ID number for patrons/borrowers
838 `surname` mediumtext NOT NULL, -- patron/borrower's last name (surname)
839 `firstname` text, -- patron/borrower's first name
840 `title` mediumtext, -- patron/borrower's title, for example: Mr. or Mrs.
841 `othernames` mediumtext, -- any other names associated with the patron/borrower
842 `initials` text, -- initials for your patron/borrower
843 `streetnumber` varchar(10) default NULL, -- the house number for your patron/borrower's primary address
844 `streettype` varchar(50) default NULL, -- the street type (Rd., Blvd, etc) for your patron/borrower's primary address
845 `address` mediumtext NOT NULL, -- the first address line for your patron/borrower's primary address
846 `address2` text, -- the second address line for your patron/borrower's primary address
847 `city` mediumtext NOT NULL, -- the city or town for your patron/borrower's primary address
848 `state` text default NULL, -- the state or province for your patron/borrower's primary address
849 `zipcode` varchar(25) default NULL, -- the zip or postal code for your patron/borrower's primary address
850 `country` text, -- the country for your patron/borrower's primary address
851 `email` mediumtext, -- the primary email address for your patron/borrower's primary address
852 `phone` text, -- the primary phone number for your patron/borrower's primary address
853 `mobile` varchar(50) default NULL, -- the other phone number for your patron/borrower's primary address
854 `fax` mediumtext, -- the fax number for your patron/borrower's primary address
855 `emailpro` text, -- the secondary email addres for your patron/borrower's primary address
856 `phonepro` text, -- the secondary phone number for your patron/borrower's primary address
857 `B_streetnumber` varchar(10) default NULL, -- the house number for your patron/borrower's alternate address
858 `B_streettype` varchar(50) default NULL, -- the street type (Rd., Blvd, etc) for your patron/borrower's alternate address
859 `B_address` varchar(100) default NULL, -- the first address line for your patron/borrower's alternate address
860 `B_address2` text default NULL, -- the second address line for your patron/borrower's alternate address
861 `B_city` mediumtext, -- the city or town for your patron/borrower's alternate address
862 `B_state` text default NULL, -- the state for your patron/borrower's alternate address
863 `B_zipcode` varchar(25) default NULL, -- the zip or postal code for your patron/borrower's alternate address
864 `B_country` text, -- the country for your patron/borrower's alternate address
865 `B_email` text, -- the patron/borrower's alternate email address
866 `B_phone` mediumtext, -- the patron/borrower's alternate phone number
867 `dateofbirth` date default NULL, -- the patron/borrower's date of birth (YYYY-MM-DD)
868 `branchcode` varchar(10) NOT NULL default '', -- foreign key from the branches table, includes the code of the patron/borrower's home branch
869 `categorycode` varchar(10) NOT NULL default '', -- foreign key from the categories table, includes the code of the patron category
870 `dateenrolled` date default NULL, -- date the patron was added to Koha (YYYY-MM-DD)
871 `dateexpiry` date default NULL, -- date the patron/borrower's card is set to expire (YYYY-MM-DD)
872 `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
873 `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
874 `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)
875 `debarredcomment` VARCHAR(255) DEFAULT NULL, -- comment on the stop of patron
876 `contactname` mediumtext, -- used for children and profesionals to include surname or last name of guarentor or organization name
877 `contactfirstname` text, -- used for children to include first name of guarentor
878 `contacttitle` text, -- used for children to include title (Mr., Mrs., etc) of guarentor
879 `guarantorid` int(11) default NULL, -- borrowernumber used for children or professionals to link them to guarentors or organizations
880 `borrowernotes` mediumtext, -- a note on the patron/borrower's account that is only visible in the staff client
881 `relationship` varchar(100) default NULL, -- used for children to include the relationship to their guarentor
882 `sex` varchar(1) default NULL, -- patron/borrower's gender
883 `password` varchar(30) default NULL, -- patron/borrower's encrypted password
884 `flags` int(11) default NULL, -- will include a number associated with the staff member's permissions
885 `userid` varchar(30) default NULL, -- patron/borrower's opac and/or staff client log in
886 `opacnote` mediumtext, -- a note on the patron/borrower's account that is visible in the OPAC and staff client
887 `contactnote` varchar(255) default NULL, -- a note related to the patron/borrower's alternate address
888 `sort1` varchar(80) default NULL, -- a field that can be used for any information unique to the library
889 `sort2` varchar(80) default NULL, -- a field that can be used for any information unique to the library
890 `altcontactfirstname` varchar(255) default NULL, -- first name of alternate contact for the patron/borrower
891 `altcontactsurname` varchar(255) default NULL, -- surname or last name of the alternate contact for the patron/borrower
892 `altcontactaddress1` varchar(255) default NULL, -- the first address line for the alternate contact for the patron/borrower
893 `altcontactaddress2` varchar(255) default NULL, -- the second address line for the alternate contact for the patron/borrower
894 `altcontactaddress3` varchar(255) default NULL, -- the city for the alternate contact for the patron/borrower
895 `altcontactstate` text default NULL, -- the state for the alternate contact for the patron/borrower
896 `altcontactzipcode` varchar(50) default NULL, -- the zipcode for the alternate contact for the patron/borrower
897 `altcontactcountry` text default NULL, -- the country for the alternate contact for the patron/borrower
898 `altcontactphone` varchar(50) default NULL, -- the phone number for the alternate contact for the patron/borrower
899 `smsalertnumber` varchar(50) default NULL, -- the mobile phone number where the patron/borrower would like to receive notices (if SNS turned on)
900 `privacy` integer(11) DEFAULT '1' NOT NULL, -- patron/borrower's privacy settings related to their reading history KEY `borrowernumber` (`borrowernumber`),
901 KEY borrowernumber (borrowernumber),
902 KEY `cardnumber` (`cardnumber`)
903 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
906 -- Table structure for table `deleteditems`
909 DROP TABLE IF EXISTS `deleteditems`;
910 CREATE TABLE `deleteditems` (
911 `itemnumber` int(11) NOT NULL default 0, -- primary key and unique identifier added by Koha
912 `biblionumber` int(11) NOT NULL default 0, -- foreign key from biblio table used to link this item to the right bib record
913 `biblioitemnumber` int(11) NOT NULL default 0, -- foreign key from the biblioitems table to link to item to additional information
914 `barcode` varchar(20) default NULL, -- item barcode (MARC21 952$p)
915 `dateaccessioned` date default NULL, -- date the item was acquired or added to Koha (MARC21 952$d)
916 `booksellerid` mediumtext default NULL, -- where the item was purchased (MARC21 952$e)
917 `homebranch` varchar(10) default NULL, -- foreign key from the branches table for the library that owns this item (MARC21 952$a)
918 `price` decimal(8,2) default NULL, -- purchase price (MARC21 952$g)
919 `replacementprice` decimal(8,2) default NULL, -- cost the library charges to replace the item if it has been marked lost (MARC21 952$v)
920 `replacementpricedate` date default NULL, -- the date the price is effective from (MARC21 952$w)
921 `datelastborrowed` date default NULL, -- the date the item was last checked out
922 `datelastseen` date default NULL, -- the date the item was last see (usually the last time the barcode was scanned or inventory was done)
923 `stack` tinyint(1) default NULL,
924 `notforloan` tinyint(1) NOT NULL default 0, -- authorized value defining why this item is not for loan (MARC21 952$7)
925 `damaged` tinyint(1) NOT NULL default 0, -- authorized value defining this item as damaged (MARC21 952$4)
926 `itemlost` tinyint(1) NOT NULL default 0, -- authorized value defining this item as lost (MARC21 952$1)
927 `itemlost_on` datetime DEFAULT NULL, -- the date and time an item was last marked as lost, NULL if not lost
928 `withdrawn` tinyint(1) NOT NULL default 0, -- authorized value defining this item as withdrawn (MARC21 952$0)
929 `withdrawn_on` datetime DEFAULT NULL, -- the date and time an item was last marked as withdrawn, NULL if not withdrawn
930 `itemcallnumber` varchar(255) default NULL, -- call number for this item (MARC21 952$o)
931 `coded_location_qualifier` varchar(10) default NULL, -- coded location qualifier(MARC21 952$f)
932 `issues` smallint(6) default NULL, -- number of times this item has been checked out
933 `renewals` smallint(6) default NULL, -- number of times this item has been renewed
934 `reserves` smallint(6) default NULL, -- number of times this item has been placed on hold/reserved
935 `restricted` tinyint(1) default NULL, -- authorized value defining use restrictions for this item (MARC21 952$5)
936 `itemnotes` mediumtext, -- public notes on this item (MARC21 952$x)
937 `itemnotes_nonpublic` mediumtext default NULL,
938 `holdingbranch` varchar(10) default NULL, -- foreign key from the branches table for the library that is currently in possession item (MARC21 952$b)
939 `paidfor` mediumtext,
940 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- date and time this item was last altered
941 `location` varchar(80) default NULL, -- authorized value for the shelving location for this item (MARC21 952$c)
942 `permanent_location` varchar(80) default NULL, -- linked to the CART and PROC temporary locations feature, stores the permanent shelving location
943 `onloan` date default NULL, -- defines if item is checked out (NULL for not checked out, and checkout date for checked out)
944 `cn_source` varchar(10) default NULL, -- classification source used on this item (MARC21 952$2)
945 `cn_sort` varchar(255) default NULL, -- normalized form of the call number (MARC21 952$o) used for sorting
946 `ccode` varchar(10) default NULL, -- authorized value for the collection code associated with this item (MARC21 952$8)
947 `materials` text default NULL, -- materials specified (MARC21 952$3)
948 `uri` varchar(255) default NULL, -- URL for the item (MARC21 952$u)
949 `itype` varchar(10) default NULL, -- foreign key from the itemtypes table defining the type for this item (MARC21 952$y)
950 `more_subfields_xml` longtext default NULL, -- additional 952 subfields in XML format
951 `enumchron` text default NULL, -- serial enumeration/chronology for the item (MARC21 952$h)
952 `copynumber` varchar(32) default NULL, -- copy number (MARC21 952$t)
953 `stocknumber` varchar(32) default NULL, -- inventory number (MARC21 952$i)
954 PRIMARY KEY (`itemnumber`),
955 KEY `delitembarcodeidx` (`barcode`),
956 KEY `delitemstocknumberidx` (`stocknumber`),
957 KEY `delitembinoidx` (`biblioitemnumber`),
958 KEY `delitembibnoidx` (`biblionumber`),
959 KEY `delhomebranch` (`homebranch`),
960 KEY `delholdingbranch` (`holdingbranch`),
961 KEY `itype_idx` (`itype`)
962 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
965 -- Table structure for table `export_format`
968 DROP TABLE IF EXISTS `export_format`;
969 CREATE TABLE `export_format` (
970 `export_format_id` int(11) NOT NULL auto_increment,
971 `profile` varchar(255) NOT NULL,
972 `description` mediumtext NOT NULL,
973 `content` mediumtext NOT NULL,
974 `csv_separator` varchar(2) NOT NULL,
975 `field_separator` varchar(2) NOT NULL,
976 `subfield_separator` varchar(2) NOT NULL,
977 `encoding` varchar(255) NOT NULL,
978 `type` varchar(255) DEFAULT 'marc',
979 PRIMARY KEY (`export_format_id`)
980 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci COMMENT='Used for CSV export';
984 -- Table structure for table `hold_fill_targets`
987 DROP TABLE IF EXISTS `hold_fill_targets`;
988 CREATE TABLE hold_fill_targets (
989 `borrowernumber` int(11) NOT NULL,
990 `biblionumber` int(11) NOT NULL,
991 `itemnumber` int(11) NOT NULL,
992 `source_branchcode` varchar(10) default NULL,
993 `item_level_request` tinyint(4) NOT NULL default 0,
994 PRIMARY KEY `itemnumber` (`itemnumber`),
995 KEY `bib_branch` (`biblionumber`, `source_branchcode`),
996 CONSTRAINT `hold_fill_targets_ibfk_1` FOREIGN KEY (`borrowernumber`)
997 REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE,
998 CONSTRAINT `hold_fill_targets_ibfk_2` FOREIGN KEY (`biblionumber`)
999 REFERENCES `biblio` (`biblionumber`) ON DELETE CASCADE ON UPDATE CASCADE,
1000 CONSTRAINT `hold_fill_targets_ibfk_3` FOREIGN KEY (`itemnumber`)
1001 REFERENCES `items` (`itemnumber`) ON DELETE CASCADE ON UPDATE CASCADE,
1002 CONSTRAINT `hold_fill_targets_ibfk_4` FOREIGN KEY (`source_branchcode`)
1003 REFERENCES `branches` (`branchcode`) ON DELETE CASCADE ON UPDATE CASCADE
1004 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1007 -- Table structure for table `import_batches`
1010 DROP TABLE IF EXISTS `import_batches`;
1011 CREATE TABLE `import_batches` ( -- information about batches of marc records that have been imported
1012 `import_batch_id` int(11) NOT NULL auto_increment, -- unique identifier and primary key
1013 `matcher_id` int(11) default NULL, -- the id of the match rule used (matchpoints.matcher_id)
1014 `template_id` int(11) default NULL,
1015 `branchcode` varchar(10) default NULL,
1016 `num_records` int(11) NOT NULL default 0, -- number of records in the file
1017 `num_items` int(11) NOT NULL default 0, -- number of items in the file
1018 `upload_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP, -- date and time the file was uploaded
1019 `overlay_action` enum('replace', 'create_new', 'use_template', 'ignore') NOT NULL default 'create_new', -- how to handle duplicate records
1020 `nomatch_action` enum('create_new', 'ignore') NOT NULL default 'create_new', -- how to handle records where no match is found
1021 `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
1022 `import_status` enum('staging', 'staged', 'importing', 'imported', 'reverting', 'reverted', 'cleaned') NOT NULL default 'staging', -- the status of the imported file
1023 `batch_type` enum('batch', 'z3950', 'webservice') NOT NULL default 'batch', -- where this batch has come from
1024 `record_type` enum('biblio', 'auth', 'holdings') NOT NULL default 'biblio', -- type of record in the batch
1025 `file_name` varchar(100), -- the name of the file uploaded
1026 `comments` mediumtext, -- any comments added when the file was uploaded
1027 PRIMARY KEY (`import_batch_id`),
1028 KEY `branchcode` (`branchcode`)
1029 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1032 -- Table structure for table `import_records`
1035 DROP TABLE IF EXISTS `import_records`;
1036 CREATE TABLE `import_records` (
1037 `import_record_id` int(11) NOT NULL auto_increment,
1038 `import_batch_id` int(11) NOT NULL,
1039 `branchcode` varchar(10) default NULL,
1040 `record_sequence` int(11) NOT NULL default 0,
1041 `upload_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP,
1042 `import_date` DATE default NULL,
1043 `marc` longblob NOT NULL,
1044 `marcxml` longtext NOT NULL,
1045 `marcxml_old` longtext NOT NULL,
1046 `record_type` enum('biblio', 'auth', 'holdings') NOT NULL default 'biblio',
1047 `overlay_status` enum('no_match', 'auto_match', 'manual_match', 'match_applied') NOT NULL default 'no_match',
1048 `status` enum('error', 'staged', 'imported', 'reverted', 'items_reverted', 'ignored') NOT NULL default 'staged',
1049 `import_error` mediumtext,
1050 `encoding` varchar(40) NOT NULL default '',
1051 `z3950random` varchar(40) default NULL,
1052 PRIMARY KEY (`import_record_id`),
1053 CONSTRAINT `import_records_ifbk_1` FOREIGN KEY (`import_batch_id`)
1054 REFERENCES `import_batches` (`import_batch_id`) ON DELETE CASCADE ON UPDATE CASCADE,
1055 KEY `branchcode` (`branchcode`),
1056 KEY `batch_sequence` (`import_batch_id`, `record_sequence`),
1057 KEY `batch_id_record_type` (`import_batch_id`,`record_type`)
1058 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1061 -- Table structure for `import_record_matches`
1063 DROP TABLE IF EXISTS `import_record_matches`;
1064 CREATE TABLE `import_record_matches` ( -- matches found when importing a batch of records
1065 `import_record_id` int(11) NOT NULL, -- the id given to the imported bib record (import_records.import_record_id)
1066 `candidate_match_id` int(11) NOT NULL, -- the biblio the imported record matches (biblio.biblionumber)
1067 `score` int(11) NOT NULL default 0, -- the match score
1068 CONSTRAINT `import_record_matches_ibfk_1` FOREIGN KEY (`import_record_id`)
1069 REFERENCES `import_records` (`import_record_id`) ON DELETE CASCADE ON UPDATE CASCADE,
1070 KEY `record_score` (`import_record_id`, `score`)
1071 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1074 -- Table structure for table `import_auths`
1077 DROP TABLE IF EXISTS `import_auths`;
1078 CREATE TABLE `import_auths` (
1079 `import_record_id` int(11) NOT NULL,
1080 `matched_authid` int(11) default NULL,
1081 `control_number` varchar(25) default NULL,
1082 `authorized_heading` varchar(128) default NULL,
1083 `original_source` varchar(25) default NULL,
1084 CONSTRAINT `import_auths_ibfk_1` FOREIGN KEY (`import_record_id`)
1085 REFERENCES `import_records` (`import_record_id`) ON DELETE CASCADE ON UPDATE CASCADE,
1086 KEY `matched_authid` (`matched_authid`)
1087 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1090 -- Table structure for table `import_biblios`
1093 DROP TABLE IF EXISTS `import_biblios`;
1094 CREATE TABLE `import_biblios` (
1095 `import_record_id` int(11) NOT NULL,
1096 `matched_biblionumber` int(11) default NULL,
1097 `control_number` varchar(25) default NULL,
1098 `original_source` varchar(25) default NULL,
1099 `title` varchar(128) default NULL,
1100 `author` varchar(80) default NULL,
1101 `isbn` varchar(30) default NULL,
1102 `issn` varchar(9) default NULL,
1103 `has_items` tinyint(1) NOT NULL default 0,
1104 CONSTRAINT `import_biblios_ibfk_1` FOREIGN KEY (`import_record_id`)
1105 REFERENCES `import_records` (`import_record_id`) ON DELETE CASCADE ON UPDATE CASCADE,
1106 KEY `matched_biblionumber` (`matched_biblionumber`),
1107 KEY `title` (`title`),
1109 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1112 -- Table structure for table `import_items`
1115 DROP TABLE IF EXISTS `import_items`;
1116 CREATE TABLE `import_items` (
1117 `import_items_id` int(11) NOT NULL auto_increment,
1118 `import_record_id` int(11) NOT NULL,
1119 `itemnumber` int(11) default NULL,
1120 `branchcode` varchar(10) default NULL,
1121 `status` enum('error', 'staged', 'imported', 'reverted', 'ignored') NOT NULL default 'staged',
1122 `marcxml` longtext NOT NULL,
1123 `import_error` mediumtext,
1124 PRIMARY KEY (`import_items_id`),
1125 CONSTRAINT `import_items_ibfk_1` FOREIGN KEY (`import_record_id`)
1126 REFERENCES `import_records` (`import_record_id`) ON DELETE CASCADE ON UPDATE CASCADE,
1127 KEY `itemnumber` (`itemnumber`),
1128 KEY `branchcode` (`branchcode`)
1129 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1132 -- Table structure for table `issues`
1135 DROP TABLE IF EXISTS `issues`;
1136 CREATE TABLE `issues` ( -- information related to check outs or issues
1137 `issue_id` int(11) NOT NULL AUTO_INCREMENT, -- primary key for issues table
1138 `borrowernumber` int(11), -- foreign key, linking this to the borrowers table for the patron this item was checked out to
1139 `itemnumber` int(11), -- foreign key, linking this to the items table for the item that was checked out
1140 `date_due` datetime default NULL, -- datetime the item is due (yyyy-mm-dd hh:mm::ss)
1141 `branchcode` varchar(10) default NULL, -- foreign key, linking to the branches table for the location the item was checked out
1142 `returndate` datetime default NULL, -- date the item was returned, will be NULL until moved to old_issues
1143 `lastreneweddate` datetime default NULL, -- date the item was last renewed
1144 `return` varchar(4) default NULL,
1145 `renewals` tinyint(4) default NULL, -- lists the number of times the item was renewed
1146 `auto_renew` BOOLEAN default FALSE, -- automatic renewal
1147 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- the date and time this record was last touched
1148 `issuedate` datetime default NULL, -- date the item was checked out or issued
1149 `onsite_checkout` int(1) NOT NULL default 0, -- in house use flag
1150 PRIMARY KEY (`issue_id`),
1151 UNIQUE KEY `itemnumber` (`itemnumber`),
1152 KEY `issuesborridx` (`borrowernumber`),
1153 KEY `itemnumber_idx` (`itemnumber`),
1154 KEY `branchcode_idx` (`branchcode`),
1155 KEY `bordate` (`borrowernumber`,`timestamp`),
1156 CONSTRAINT `issues_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE RESTRICT ON UPDATE CASCADE,
1157 CONSTRAINT `issues_ibfk_2` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`) ON DELETE RESTRICT ON UPDATE CASCADE
1158 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1161 -- Table structure for table `issuingrules`
1164 DROP TABLE IF EXISTS `issuingrules`;
1165 CREATE TABLE `issuingrules` ( -- circulation and fine rules
1166 `categorycode` varchar(10) NOT NULL default '', -- patron category this rule is for (categories.categorycode)
1167 `itemtype` varchar(10) NOT NULL default '', -- item type this rule is for (itemtypes.itemtype)
1168 `restrictedtype` tinyint(1) default NULL, -- not used? always NULL
1169 `rentaldiscount` decimal(28,6) default NULL, -- percent discount on the rental charge for this item
1170 `reservecharge` decimal(28,6) default NULL,
1171 `fine` decimal(28,6) default NULL, -- fine amount
1172 `finedays` int(11) default NULL, -- suspension in days
1173 `maxsuspensiondays` int(11) default NULL, -- max suspension days
1174 `firstremind` int(11) default NULL, -- fine grace period
1175 `chargeperiod` int(11) default NULL, -- how often the fine amount is charged
1176 `chargeperiod_charge_at` tinyint(1) NOT NULL DEFAULT '0', -- Should fine be given at the start ( 1 ) or the end ( 0 ) of the period
1177 `accountsent` int(11) default NULL, -- not used? always NULL
1178 `chargename` varchar(100) default NULL, -- not used? always NULL
1179 `maxissueqty` int(4) default NULL, -- total number of checkouts allowed
1180 `maxonsiteissueqty` int(4) default NULL, -- total number of on-site checkouts allowed
1181 `issuelength` int(4) default NULL, -- length of checkout in the unit set in issuingrules.lengthunit
1182 `lengthunit` varchar(10) default 'days', -- unit of checkout length (days, hours)
1183 `hardduedate` date default NULL, -- hard due date
1184 `hardduedatecompare` tinyint NOT NULL default "0", -- type of hard due date (1 = after, 0 = on, -1 = before)
1185 `renewalsallowed` smallint(6) NOT NULL default "0", -- how many renewals are allowed
1186 `renewalperiod` int(4) default NULL, -- renewal period in the unit set in issuingrules.lengthunit
1187 `norenewalbefore` int(4) default NULL, -- no renewal allowed until X days or hours before due date. In the unit set in issuingrules.lengthunit
1188 `auto_renew` BOOLEAN default FALSE, -- automatic renewal
1189 `reservesallowed` smallint(6) NOT NULL default "0", -- how many holds are allowed
1190 `branchcode` varchar(10) NOT NULL default '', -- the branch this rule is for (branches.branchcode)
1191 overduefinescap decimal(28,6) default NULL, -- the maximum amount of an overdue fine
1192 onshelfholds tinyint(1) NOT NULL default 0, -- allow holds for items that are on shelf
1193 opacitemholds char(1) NOT NULL default 'N', -- allow opac users to place specific items on hold
1194 PRIMARY KEY (`branchcode`,`categorycode`,`itemtype`),
1195 KEY `categorycode` (`categorycode`),
1196 KEY `itemtype` (`itemtype`)
1197 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1200 -- Table structure for table `items`
1203 DROP TABLE IF EXISTS `items`;
1204 CREATE TABLE `items` ( -- holdings/item information
1205 `itemnumber` int(11) NOT NULL auto_increment, -- primary key and unique identifier added by Koha
1206 `biblionumber` int(11) NOT NULL default 0, -- foreign key from biblio table used to link this item to the right bib record
1207 `biblioitemnumber` int(11) NOT NULL default 0, -- foreign key from the biblioitems table to link to item to additional information
1208 `barcode` varchar(20) default NULL, -- item barcode (MARC21 952$p)
1209 `dateaccessioned` date default NULL, -- date the item was acquired or added to Koha (MARC21 952$d)
1210 `booksellerid` mediumtext default NULL, -- where the item was purchased (MARC21 952$e)
1211 `homebranch` varchar(10) default NULL, -- foreign key from the branches table for the library that owns this item (MARC21 952$a)
1212 `price` decimal(8,2) default NULL, -- purchase price (MARC21 952$g)
1213 `replacementprice` decimal(8,2) default NULL, -- cost the library charges to replace the item if it has been marked lost (MARC21 952$v)
1214 `replacementpricedate` date default NULL, -- the date the price is effective from (MARC21 952$w)
1215 `datelastborrowed` date default NULL, -- the date the item was last checked out/issued
1216 `datelastseen` date default NULL, -- the date the item was last see (usually the last time the barcode was scanned or inventory was done)
1217 `stack` tinyint(1) default NULL,
1218 `notforloan` tinyint(1) NOT NULL default 0, -- authorized value defining why this item is not for loan (MARC21 952$7)
1219 `damaged` tinyint(1) NOT NULL default 0, -- authorized value defining this item as damaged (MARC21 952$4)
1220 `itemlost` tinyint(1) NOT NULL default 0, -- authorized value defining this item as lost (MARC21 952$1)
1221 `itemlost_on` datetime DEFAULT NULL, -- the date and time an item was last marked as lost, NULL if not lost
1222 `withdrawn` tinyint(1) NOT NULL default 0, -- authorized value defining this item as withdrawn (MARC21 952$0)
1223 `withdrawn_on` datetime DEFAULT NULL, -- the date and time an item was last marked as withdrawn, NULL if not withdrawn
1224 `itemcallnumber` varchar(255) default NULL, -- call number for this item (MARC21 952$o)
1225 `coded_location_qualifier` varchar(10) default NULL, -- coded location qualifier(MARC21 952$f)
1226 `issues` smallint(6) default NULL, -- number of times this item has been checked out/issued
1227 `renewals` smallint(6) default NULL, -- number of times this item has been renewed
1228 `reserves` smallint(6) default NULL, -- number of times this item has been placed on hold/reserved
1229 `restricted` tinyint(1) default NULL, -- authorized value defining use restrictions for this item (MARC21 952$5)
1230 `itemnotes` mediumtext, -- public notes on this item (MARC21 952$x)
1231 `itemnotes_nonpublic` mediumtext default NULL,
1232 `holdingbranch` varchar(10) default NULL, -- foreign key from the branches table for the library that is currently in possession item (MARC21 952$b)
1233 `paidfor` mediumtext,
1234 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- date and time this item was last altered
1235 `location` varchar(80) default NULL, -- authorized value for the shelving location for this item (MARC21 952$c)
1236 `permanent_location` varchar(80) default NULL, -- linked to the CART and PROC temporary locations feature, stores the permanent shelving location
1237 `onloan` date default NULL, -- defines if item is checked out (NULL for not checked out, and checkout date for checked out)
1238 `cn_source` varchar(10) default NULL, -- classification source used on this item (MARC21 952$2)
1239 `cn_sort` varchar(255) default NULL, -- normalized form of the call number (MARC21 952$o) used for sorting
1240 `ccode` varchar(10) default NULL, -- authorized value for the collection code associated with this item (MARC21 952$8)
1241 `materials` text default NULL, -- materials specified (MARC21 952$3)
1242 `uri` varchar(255) default NULL, -- URL for the item (MARC21 952$u)
1243 `itype` varchar(10) default NULL, -- foreign key from the itemtypes table defining the type for this item (MARC21 952$y)
1244 `more_subfields_xml` longtext default NULL, -- additional 952 subfields in XML format
1245 `enumchron` text default NULL, -- serial enumeration/chronology for the item (MARC21 952$h)
1246 `copynumber` varchar(32) default NULL, -- copy number (MARC21 952$t)
1247 `stocknumber` varchar(32) default NULL, -- inventory number (MARC21 952$i)
1248 PRIMARY KEY (`itemnumber`),
1249 UNIQUE KEY `itembarcodeidx` (`barcode`),
1250 KEY `itemstocknumberidx` (`stocknumber`),
1251 KEY `itembinoidx` (`biblioitemnumber`),
1252 KEY `itembibnoidx` (`biblionumber`),
1253 KEY `homebranch` (`homebranch`),
1254 KEY `holdingbranch` (`holdingbranch`),
1255 KEY `itemcallnumber` (`itemcallnumber`),
1256 KEY `items_location` (`location`),
1257 KEY `items_ccode` (`ccode`),
1258 KEY `itype_idx` (`itype`),
1259 CONSTRAINT `items_ibfk_1` FOREIGN KEY (`biblioitemnumber`) REFERENCES `biblioitems` (`biblioitemnumber`) ON DELETE CASCADE ON UPDATE CASCADE,
1260 CONSTRAINT `items_ibfk_2` FOREIGN KEY (`homebranch`) REFERENCES `branches` (`branchcode`) ON UPDATE CASCADE,
1261 CONSTRAINT `items_ibfk_3` FOREIGN KEY (`holdingbranch`) REFERENCES `branches` (`branchcode`) ON UPDATE CASCADE
1262 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1265 -- Table structure for table `itemtypes`
1268 DROP TABLE IF EXISTS `itemtypes`;
1269 CREATE TABLE `itemtypes` ( -- defines the item types
1270 itemtype varchar(10) NOT NULL default '', -- unique key, a code associated with the item type
1271 description mediumtext, -- a plain text explanation of the item type
1272 rentalcharge double(16,4) default NULL, -- the amount charged when this item is checked out/issued
1273 notforloan smallint(6) default NULL, -- 1 if the item is not for loan, 0 if the item is available for loan
1274 imageurl varchar(200) default NULL, -- URL for the item type icon
1275 summary text, -- information from the summary field, may include HTML
1276 checkinmsg VARCHAR(255), -- message that is displayed when an item with the given item type is checked in
1277 checkinmsgtype CHAR(16) DEFAULT 'message' NOT NULL, -- type (CSS class) for the checkinmsg, can be "alert" or "message"
1278 sip_media_type VARCHAR(3) DEFAULT NULL, -- SIP2 protocol media type for this itemtype
1279 hideinopac tinyint(1) NOT NULL DEFAULT 0, -- Hide the item type from the search options in OPAC
1280 searchcategory varchar(80) default NULL, -- Group this item type with others with the same value on OPAC search options
1281 PRIMARY KEY (`itemtype`),
1282 UNIQUE KEY `itemtype` (`itemtype`)
1283 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1286 -- Table structure for table `creator_batches`
1289 DROP TABLE IF EXISTS `creator_batches`;
1290 SET @saved_cs_client = @@character_set_client;
1291 SET character_set_client = utf8;
1292 CREATE TABLE `creator_batches` (
1293 `label_id` int(11) NOT NULL AUTO_INCREMENT,
1294 `batch_id` int(10) NOT NULL DEFAULT '1',
1295 `item_number` int(11) DEFAULT NULL,
1296 `borrower_number` int(11) DEFAULT NULL,
1297 `timestamp` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
1298 `branch_code` varchar(10) NOT NULL DEFAULT 'NB',
1299 `creator` char(15) NOT NULL DEFAULT 'Labels',
1300 PRIMARY KEY (`label_id`),
1301 KEY `branch_fk_constraint` (`branch_code`),
1302 KEY `item_fk_constraint` (`item_number`),
1303 KEY `borrower_fk_constraint` (`borrower_number`),
1304 CONSTRAINT `creator_batches_ibfk_1` FOREIGN KEY (`borrower_number`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE,
1305 CONSTRAINT `creator_batches_ibfk_2` FOREIGN KEY (`branch_code`) REFERENCES `branches` (`branchcode`) ON DELETE CASCADE,
1306 CONSTRAINT `creator_batches_ibfk_3` FOREIGN KEY (`item_number`) REFERENCES `items` (`itemnumber`) ON DELETE CASCADE
1307 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1310 -- Table structure for table `creator_images`
1313 DROP TABLE IF EXISTS `creator_images`;
1314 SET @saved_cs_client = @@character_set_client;
1315 SET character_set_client = utf8;
1316 CREATE TABLE `creator_images` (
1317 `image_id` int(4) NOT NULL AUTO_INCREMENT,
1318 `imagefile` mediumblob,
1319 `image_name` char(20) NOT NULL DEFAULT 'DEFAULT',
1320 PRIMARY KEY (`image_id`),
1321 UNIQUE KEY `image_name_index` (`image_name`)
1322 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1325 -- Table structure for table `creator_layouts`
1328 DROP TABLE IF EXISTS `creator_layouts`;
1329 SET @saved_cs_client = @@character_set_client;
1330 SET character_set_client = utf8;
1331 CREATE TABLE `creator_layouts` (
1332 `layout_id` int(4) NOT NULL AUTO_INCREMENT,
1333 `barcode_type` char(100) NOT NULL DEFAULT 'CODE39',
1334 `start_label` int(2) NOT NULL DEFAULT '1',
1335 `printing_type` char(32) NOT NULL DEFAULT 'BAR',
1336 `layout_name` char(20) NOT NULL DEFAULT 'DEFAULT',
1337 `guidebox` int(1) DEFAULT '0',
1338 `oblique_title` int(1) DEFAULT '1',
1339 `font` char(10) CHARACTER SET utf8 COLLATE utf8_unicode_ci NOT NULL DEFAULT 'TR',
1340 `font_size` int(4) NOT NULL DEFAULT '10',
1341 `units` char(20) NOT NULL DEFAULT 'POINT',
1342 `callnum_split` int(1) DEFAULT '0',
1343 `text_justify` char(1) CHARACTER SET utf8 COLLATE utf8_unicode_ci NOT NULL DEFAULT 'L',
1344 `format_string` varchar(210) NOT NULL DEFAULT 'barcode',
1345 `layout_xml` text NOT NULL,
1346 `creator` char(15) NOT NULL DEFAULT 'Labels',
1347 PRIMARY KEY (`layout_id`)
1348 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1351 -- Table structure for table `creator_templates`
1354 DROP TABLE IF EXISTS `creator_templates`;
1355 SET @saved_cs_client = @@character_set_client;
1356 SET character_set_client = utf8;
1357 CREATE TABLE `creator_templates` (
1358 `template_id` int(4) NOT NULL AUTO_INCREMENT,
1359 `profile_id` int(4) DEFAULT NULL,
1360 `template_code` char(100) NOT NULL DEFAULT 'DEFAULT TEMPLATE',
1361 `template_desc` char(100) NOT NULL DEFAULT 'Default description',
1362 `page_width` float NOT NULL DEFAULT '0',
1363 `page_height` float NOT NULL DEFAULT '0',
1364 `label_width` float NOT NULL DEFAULT '0',
1365 `label_height` float NOT NULL DEFAULT '0',
1366 `top_text_margin` float NOT NULL DEFAULT '0',
1367 `left_text_margin` float NOT NULL DEFAULT '0',
1368 `top_margin` float NOT NULL DEFAULT '0',
1369 `left_margin` float NOT NULL DEFAULT '0',
1370 `cols` int(2) NOT NULL DEFAULT '0',
1371 `rows` int(2) NOT NULL DEFAULT '0',
1372 `col_gap` float NOT NULL DEFAULT '0',
1373 `row_gap` float NOT NULL DEFAULT '0',
1374 `units` char(20) NOT NULL DEFAULT 'POINT',
1375 `creator` char(15) NOT NULL DEFAULT 'Labels',
1376 PRIMARY KEY (`template_id`),
1377 KEY `template_profile_fk_constraint` (`profile_id`)
1378 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1381 -- Table structure for table `letter`
1384 DROP TABLE IF EXISTS `letter`;
1385 CREATE TABLE `letter` ( -- table for all notice templates in Koha
1386 `module` varchar(20) NOT NULL default '', -- Koha module that triggers this notice or slip
1387 `code` varchar(20) NOT NULL default '', -- unique identifier for this notice or slip
1388 `branchcode` varchar(10) default NULL, -- the branch this notice or slip is used at (branches.branchcode)
1389 `name` varchar(100) NOT NULL default '', -- plain text name for this notice or slip
1390 `is_html` tinyint(1) default 0, -- does this notice or slip use HTML (1 for yes, 0 for no)
1391 `title` varchar(200) NOT NULL default '', -- subject line of the notice
1392 `content` text, -- body text for the notice or slip
1393 `message_transport_type` varchar(20) NOT NULL DEFAULT 'email', -- transport type for this notice
1394 PRIMARY KEY (`module`,`code`, `branchcode`, `message_transport_type`),
1395 CONSTRAINT `message_transport_type_fk` FOREIGN KEY (`message_transport_type`)
1396 REFERENCES `message_transport_types` (`message_transport_type`) ON DELETE CASCADE ON UPDATE CASCADE
1397 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1400 -- Table structure for table `marc_subfield_structure`
1403 DROP TABLE IF EXISTS `marc_subfield_structure`;
1404 CREATE TABLE `marc_subfield_structure` (
1405 `tagfield` varchar(3) NOT NULL default '',
1406 `tagsubfield` varchar(1) NOT NULL default '' COLLATE utf8_bin,
1407 `liblibrarian` varchar(255) NOT NULL default '',
1408 `libopac` varchar(255) NOT NULL default '',
1409 `repeatable` tinyint(4) NOT NULL default 0,
1410 `mandatory` tinyint(4) NOT NULL default 0,
1411 `kohafield` varchar(40) default NULL,
1412 `tab` tinyint(1) default NULL,
1413 `authorised_value` varchar(20) default NULL,
1414 `authtypecode` varchar(20) default NULL,
1415 `value_builder` varchar(80) default NULL,
1416 `isurl` tinyint(1) default NULL,
1417 `hidden` tinyint(1) default NULL,
1418 `frameworkcode` varchar(4) NOT NULL default '',
1419 `seealso` varchar(1100) default NULL,
1420 `link` varchar(80) default NULL,
1421 `defaultvalue` text default NULL,
1422 `maxlength` int(4) NOT NULL DEFAULT '9999',
1423 PRIMARY KEY (`frameworkcode`,`tagfield`,`tagsubfield`),
1424 KEY `kohafield_2` (`kohafield`),
1425 KEY `tab` (`frameworkcode`,`tab`),
1426 KEY `kohafield` (`frameworkcode`,`kohafield`)
1427 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1430 -- Table structure for table `marc_tag_structure`
1433 DROP TABLE IF EXISTS `marc_tag_structure`;
1434 CREATE TABLE `marc_tag_structure` (
1435 `tagfield` varchar(3) NOT NULL default '',
1436 `liblibrarian` varchar(255) NOT NULL default '',
1437 `libopac` varchar(255) NOT NULL default '',
1438 `repeatable` tinyint(4) NOT NULL default 0,
1439 `mandatory` tinyint(4) NOT NULL default 0,
1440 `authorised_value` varchar(10) default NULL,
1441 `frameworkcode` varchar(4) NOT NULL default '',
1442 PRIMARY KEY (`frameworkcode`,`tagfield`)
1443 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1446 -- Table structure for table `marc_matchers`
1449 DROP TABLE IF EXISTS `marc_matchers`;
1450 CREATE TABLE `marc_matchers` (
1451 `matcher_id` int(11) NOT NULL auto_increment,
1452 `code` varchar(10) NOT NULL default '',
1453 `description` varchar(255) NOT NULL default '',
1454 `record_type` varchar(10) NOT NULL default 'biblio',
1455 `threshold` int(11) NOT NULL default 0,
1456 PRIMARY KEY (`matcher_id`),
1457 KEY `code` (`code`),
1458 KEY `record_type` (`record_type`)
1459 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1462 -- Table structure for table `matchpoints`
1464 DROP TABLE IF EXISTS `matchpoints`;
1465 CREATE TABLE `matchpoints` (
1466 `matcher_id` int(11) NOT NULL,
1467 `matchpoint_id` int(11) NOT NULL auto_increment,
1468 `search_index` varchar(30) NOT NULL default '',
1469 `score` int(11) NOT NULL default 0,
1470 PRIMARY KEY (`matchpoint_id`),
1471 CONSTRAINT `matchpoints_ifbk_1` FOREIGN KEY (`matcher_id`)
1472 REFERENCES `marc_matchers` (`matcher_id`) ON DELETE CASCADE ON UPDATE CASCADE
1473 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1477 -- Table structure for table `matchpoint_components`
1479 DROP TABLE IF EXISTS `matchpoint_components`;
1480 CREATE TABLE `matchpoint_components` (
1481 `matchpoint_id` int(11) NOT NULL,
1482 `matchpoint_component_id` int(11) NOT NULL auto_increment,
1483 sequence int(11) NOT NULL default 0,
1484 tag varchar(3) NOT NULL default '',
1485 subfields varchar(40) NOT NULL default '',
1486 offset int(4) NOT NULL default 0,
1487 length int(4) NOT NULL default 0,
1488 PRIMARY KEY (`matchpoint_component_id`),
1489 KEY `by_sequence` (`matchpoint_id`, `sequence`),
1490 CONSTRAINT `matchpoint_components_ifbk_1` FOREIGN KEY (`matchpoint_id`)
1491 REFERENCES `matchpoints` (`matchpoint_id`) ON DELETE CASCADE ON UPDATE CASCADE
1492 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1495 -- Table structure for table `matcher_component_norms`
1497 DROP TABLE IF EXISTS `matchpoint_component_norms`;
1498 CREATE TABLE `matchpoint_component_norms` (
1499 `matchpoint_component_id` int(11) NOT NULL,
1500 `sequence` int(11) NOT NULL default 0,
1501 `norm_routine` varchar(50) NOT NULL default '',
1502 KEY `matchpoint_component_norms` (`matchpoint_component_id`, `sequence`),
1503 CONSTRAINT `matchpoint_component_norms_ifbk_1` FOREIGN KEY (`matchpoint_component_id`)
1504 REFERENCES `matchpoint_components` (`matchpoint_component_id`) ON DELETE CASCADE ON UPDATE CASCADE
1505 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1508 -- Table structure for table `matcher_matchpoints`
1510 DROP TABLE IF EXISTS `matcher_matchpoints`;
1511 CREATE TABLE `matcher_matchpoints` (
1512 `matcher_id` int(11) NOT NULL,
1513 `matchpoint_id` int(11) NOT NULL,
1514 CONSTRAINT `matcher_matchpoints_ifbk_1` FOREIGN KEY (`matcher_id`)
1515 REFERENCES `marc_matchers` (`matcher_id`) ON DELETE CASCADE ON UPDATE CASCADE,
1516 CONSTRAINT `matcher_matchpoints_ifbk_2` FOREIGN KEY (`matchpoint_id`)
1517 REFERENCES `matchpoints` (`matchpoint_id`) ON DELETE CASCADE ON UPDATE CASCADE
1518 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1521 -- Table structure for table `matchchecks`
1523 DROP TABLE IF EXISTS `matchchecks`;
1524 CREATE TABLE `matchchecks` (
1525 `matcher_id` int(11) NOT NULL,
1526 `matchcheck_id` int(11) NOT NULL auto_increment,
1527 `source_matchpoint_id` int(11) NOT NULL,
1528 `target_matchpoint_id` int(11) NOT NULL,
1529 PRIMARY KEY (`matchcheck_id`),
1530 CONSTRAINT `matcher_matchchecks_ifbk_1` FOREIGN KEY (`matcher_id`)
1531 REFERENCES `marc_matchers` (`matcher_id`) ON DELETE CASCADE ON UPDATE CASCADE,
1532 CONSTRAINT `matcher_matchchecks_ifbk_2` FOREIGN KEY (`source_matchpoint_id`)
1533 REFERENCES `matchpoints` (`matchpoint_id`) ON DELETE CASCADE ON UPDATE CASCADE,
1534 CONSTRAINT `matcher_matchchecks_ifbk_3` FOREIGN KEY (`target_matchpoint_id`)
1535 REFERENCES `matchpoints` (`matchpoint_id`) ON DELETE CASCADE ON UPDATE CASCADE
1536 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1539 -- Table structure for table `need_merge_authorities`
1542 DROP TABLE IF EXISTS `need_merge_authorities`;
1543 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)
1544 `id` int NOT NULL auto_increment PRIMARY KEY, -- unique id
1545 `authid` bigint NOT NULL, -- reference to authority record
1546 `done` tinyint DEFAULT 0 -- indication whether merge has been executed (0=not done, 1= done, 2= in progress)
1547 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1550 -- Table structure for table `notifys`
1553 DROP TABLE IF EXISTS `notifys`;
1554 CREATE TABLE `notifys` (
1555 `notify_id` int(11) NOT NULL default 0,
1556 `borrowernumber` int(11) NOT NULL default 0,
1557 `itemnumber` int(11) NOT NULL default 0,
1558 `notify_date` date default NULL,
1559 `notify_send_date` date default NULL,
1560 `notify_level` int(1) NOT NULL default 0,
1561 `method` varchar(20) NOT NULL default ''
1562 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1565 -- Table structure for table `oai_sets`
1568 DROP TABLE IF EXISTS `oai_sets`;
1569 CREATE TABLE `oai_sets` (
1570 `id` int(11) NOT NULL auto_increment,
1571 `spec` varchar(80) NOT NULL UNIQUE,
1572 `name` varchar(80) NOT NULL,
1574 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1577 -- Table structure for table `oai_sets_descriptions`
1580 DROP TABLE IF EXISTS `oai_sets_descriptions`;
1581 CREATE TABLE `oai_sets_descriptions` (
1582 `set_id` int(11) NOT NULL,
1583 `description` varchar(255) NOT NULL,
1584 CONSTRAINT `oai_sets_descriptions_ibfk_1` FOREIGN KEY (`set_id`) REFERENCES `oai_sets` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
1585 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1588 -- Table structure for table `oai_sets_mappings`
1591 DROP TABLE IF EXISTS `oai_sets_mappings`;
1592 CREATE TABLE `oai_sets_mappings` (
1593 `set_id` int(11) NOT NULL,
1594 `marcfield` char(3) NOT NULL,
1595 `marcsubfield` char(1) NOT NULL,
1596 `operator` varchar(8) NOT NULL default 'equal',
1597 `marcvalue` varchar(80) NOT NULL,
1598 CONSTRAINT `oai_sets_mappings_ibfk_1` FOREIGN KEY (`set_id`) REFERENCES `oai_sets` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
1599 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1602 -- Table structure for table `oai_sets_biblios`
1605 DROP TABLE IF EXISTS `oai_sets_biblios`;
1606 CREATE TABLE `oai_sets_biblios` (
1607 `biblionumber` int(11) NOT NULL,
1608 `set_id` int(11) NOT NULL,
1609 PRIMARY KEY (`biblionumber`, `set_id`),
1610 CONSTRAINT `oai_sets_biblios_ibfk_2` FOREIGN KEY (`set_id`) REFERENCES `oai_sets` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
1611 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1614 -- Table structure for table `old_issues`
1617 DROP TABLE IF EXISTS `old_issues`;
1618 CREATE TABLE `old_issues` ( -- lists items that were checked out and have been returned
1619 `issue_id` int(11) NOT NULL, -- primary key for issues table
1620 `borrowernumber` int(11) default NULL, -- foreign key, linking this to the borrowers table for the patron this item was checked out to
1621 `itemnumber` int(11) default NULL, -- foreign key, linking this to the items table for the item that was checked out
1622 `date_due` datetime default NULL, -- date the item is due (yyyy-mm-dd)
1623 `branchcode` varchar(10) default NULL, -- foreign key, linking to the branches table for the location the item was checked out
1624 `returndate` datetime default NULL, -- date the item was returned
1625 `lastreneweddate` datetime default NULL, -- date the item was last renewed
1626 `return` varchar(4) default NULL,
1627 `renewals` tinyint(4) default NULL, -- lists the number of times the item was renewed
1628 `auto_renew` BOOLEAN default FALSE, -- automatic renewal
1629 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- the date and time this record was last touched
1630 `issuedate` datetime default NULL, -- date the item was checked out or issued
1631 `onsite_checkout` int(1) NOT NULL default 0, -- in house use flag
1632 PRIMARY KEY (`issue_id`),
1633 KEY `old_issuesborridx` (`borrowernumber`),
1634 KEY `old_issuesitemidx` (`itemnumber`),
1635 KEY `branchcode_idx` (`branchcode`),
1636 KEY `old_bordate` (`borrowernumber`,`timestamp`),
1637 CONSTRAINT `old_issues_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`)
1638 ON DELETE SET NULL ON UPDATE SET NULL,
1639 CONSTRAINT `old_issues_ibfk_2` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`)
1640 ON DELETE SET NULL ON UPDATE SET NULL
1641 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1644 -- Table structure for table `old_reserves`
1646 DROP TABLE IF EXISTS `old_reserves`;
1647 CREATE TABLE `old_reserves` ( -- this table holds all holds/reserves that have been completed (either filled or cancelled)
1648 `reserve_id` int(11) NOT NULL, -- primary key
1649 `borrowernumber` int(11) default NULL, -- foreign key from the borrowers table defining which patron this hold is for
1650 `reservedate` date default NULL, -- the date the hold was places
1651 `biblionumber` int(11) default NULL, -- foreign key from the biblio table defining which bib record this hold is on
1652 `branchcode` varchar(10) default NULL, -- foreign key from the branches table defining which branch the patron wishes to pick this hold up at
1653 `notificationdate` date default NULL, -- currently unused
1654 `reminderdate` date default NULL, -- currently unused
1655 `cancellationdate` date default NULL, -- the date this hold was cancelled
1656 `reservenotes` mediumtext, -- notes related to this hold
1657 `priority` smallint(6) default NULL, -- where in the queue the patron sits
1658 `found` varchar(1) default NULL, -- a one letter code defining what the status is of the hold is after it has been confirmed
1659 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- the date and time this hold was last updated
1660 `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
1661 `waitingdate` date default NULL, -- the date the item was marked as waiting for the patron at the library
1662 `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)
1663 `lowestPriority` tinyint(1) NOT NULL, -- has this hold been pinned to the lowest priority in the holds queue (1 for yes, 0 for no)
1664 `suspend` BOOLEAN NOT NULL DEFAULT 0, -- in this hold suspended (1 for yes, 0 for no)
1665 `suspend_until` DATETIME NULL DEFAULT NULL, -- the date this hold is suspended until (NULL for infinitely)
1666 PRIMARY KEY (`reserve_id`),
1667 KEY `old_reserves_borrowernumber` (`borrowernumber`),
1668 KEY `old_reserves_biblionumber` (`biblionumber`),
1669 KEY `old_reserves_itemnumber` (`itemnumber`),
1670 KEY `old_reserves_branchcode` (`branchcode`),
1671 CONSTRAINT `old_reserves_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`)
1672 ON DELETE SET NULL ON UPDATE SET NULL,
1673 CONSTRAINT `old_reserves_ibfk_2` FOREIGN KEY (`biblionumber`) REFERENCES `biblio` (`biblionumber`)
1674 ON DELETE SET NULL ON UPDATE SET NULL,
1675 CONSTRAINT `old_reserves_ibfk_3` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`)
1676 ON DELETE SET NULL ON UPDATE SET NULL
1677 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1680 -- Table structure for table `opac_news`
1683 DROP TABLE IF EXISTS `opac_news`;
1684 CREATE TABLE `opac_news` ( -- data from the news tool
1685 `idnew` int(10) unsigned NOT NULL auto_increment, -- unique identifier for the news article
1686 `branchcode` varchar(10) default NULL, -- branch code users to create branch specific news, NULL is every branch.
1687 `title` varchar(250) NOT NULL default '', -- title of the news article
1688 `new` text NOT NULL, -- the body of your news article
1689 `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)
1690 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP, -- pulibcation date and time
1691 `expirationdate` date default NULL, -- date the article is set to expire or no longer be visible
1692 `number` int(11) default NULL, -- the order in which this article appears in that specific location
1693 `borrowernumber` int(11) default NULL, -- The user who created the news article
1694 PRIMARY KEY (`idnew`),
1695 CONSTRAINT `borrowernumber_fk` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE SET NULL ON UPDATE CASCADE,
1696 CONSTRAINT opac_news_branchcode_ibfk FOREIGN KEY (branchcode) REFERENCES branches (branchcode)
1697 ON DELETE CASCADE ON UPDATE CASCADE
1698 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1701 -- Table structure for table `overduerules`
1704 DROP TABLE IF EXISTS `overduerules`;
1705 CREATE TABLE `overduerules` ( -- overdue notice status and triggers
1706 `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)
1707 `categorycode` varchar(10) NOT NULL default '', -- foreign key from the categories table to define which patron category this rule is for
1708 `delay1` int(4) default NULL, -- number of days after the item is overdue that the first notice is sent
1709 `letter1` varchar(20) default NULL, -- foreign key from the letter table to define which notice should be sent as the first notice
1710 `debarred1` varchar(1) default 0, -- is the patron restricted when the first notice is sent (1 for yes, 0 for no)
1711 `delay2` int(4) default NULL, -- number of days after the item is overdue that the second notice is sent
1712 `debarred2` varchar(1) default 0, -- is the patron restricted when the second notice is sent (1 for yes, 0 for no)
1713 `letter2` varchar(20) default NULL, -- foreign key from the letter table to define which notice should be sent as the second notice
1714 `delay3` int(4) default NULL, -- number of days after the item is overdue that the third notice is sent
1715 `letter3` varchar(20) default NULL, -- foreign key from the letter table to define which notice should be sent as the third notice
1716 `debarred3` int(1) default 0, -- is the patron restricted when the third notice is sent (1 for yes, 0 for no)
1717 PRIMARY KEY (`branchcode`,`categorycode`)
1718 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1721 -- Table structure for table `patronimage`
1724 DROP TABLE IF EXISTS `patronimage`;
1725 CREATE TABLE `patronimage` ( -- information related to patron images
1726 `borrowernumber` int(11) NOT NULL, -- the borrowernumber of the patron this image is attached to (borrowers.borrowernumber)
1727 `mimetype` varchar(15) NOT NULL, -- the format of the image (png, jpg, etc)
1728 `imagefile` mediumblob NOT NULL, -- the image
1729 PRIMARY KEY (`borrowernumber`),
1730 CONSTRAINT `patronimage_fk1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE
1731 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1733 -- Table structure for table `pending_offline_operations`
1735 -- this table is MyISAM, InnoDB tables are growing only and this table is filled/emptied/filled/emptied...
1736 -- so MyISAM is better in this case
1738 DROP TABLE IF EXISTS `pending_offline_operations`;
1739 CREATE TABLE pending_offline_operations (
1740 operationid int(11) NOT NULL AUTO_INCREMENT,
1741 userid varchar(30) NOT NULL,
1742 branchcode varchar(10) NOT NULL,
1743 `timestamp` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
1744 `action` varchar(10) NOT NULL,
1745 barcode varchar(20) DEFAULT NULL,
1746 cardnumber varchar(16) DEFAULT NULL,
1747 amount decimal(28,6) DEFAULT NULL,
1748 PRIMARY KEY (operationid)
1749 ) ENGINE=MyISAM DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1753 -- Table structure for table `printers`
1756 DROP TABLE IF EXISTS `printers`;
1757 CREATE TABLE `printers` (
1758 `printername` varchar(40) NOT NULL default '',
1759 `printqueue` varchar(20) default NULL,
1760 `printtype` varchar(20) default NULL,
1761 PRIMARY KEY (`printername`)
1762 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1765 -- Table structure for table `printers_profile`
1768 DROP TABLE IF EXISTS `printers_profile`;
1769 CREATE TABLE `printers_profile` (
1770 `profile_id` int(4) NOT NULL auto_increment,
1771 `printer_name` varchar(40) NOT NULL default 'Default Printer',
1772 `template_id` int(4) NOT NULL default '0',
1773 `paper_bin` varchar(20) NOT NULL default 'Bypass',
1774 `offset_horz` float NOT NULL default '0',
1775 `offset_vert` float NOT NULL default '0',
1776 `creep_horz` float NOT NULL default '0',
1777 `creep_vert` float NOT NULL default '0',
1778 `units` char(20) NOT NULL default 'POINT',
1779 `creator` char(15) NOT NULL DEFAULT 'Labels',
1780 PRIMARY KEY (`profile_id`),
1781 UNIQUE KEY `printername` (`printer_name`,`template_id`,`paper_bin`,`creator`)
1782 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1785 -- Table structure for table `repeatable_holidays`
1788 DROP TABLE IF EXISTS `repeatable_holidays`;
1789 CREATE TABLE `repeatable_holidays` ( -- information for the days the library is closed
1790 `id` int(11) NOT NULL auto_increment, -- unique identifier assigned by Koha
1791 `branchcode` varchar(10) NOT NULL default '', -- foreign key from the branches table, defines which branch this closing is for
1792 `weekday` smallint(6) default NULL, -- day of the week (0=Sunday, 1=Monday, etc) this closing is repeated on
1793 `day` smallint(6) default NULL, -- day of the month this closing is on
1794 `month` smallint(6) default NULL, -- month this closing is in
1795 `title` varchar(50) NOT NULL default '', -- title of this closing
1796 `description` text NOT NULL, -- description for this closing
1798 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1801 -- Table structure for table `reports_dictionary`
1804 DROP TABLE IF EXISTS `reports_dictionary`;
1805 CREATE TABLE reports_dictionary ( -- definitions (or snippets of SQL) stored for use in reports
1806 `id` int(11) NOT NULL auto_increment, -- unique identifier assigned by Koha
1807 `name` varchar(255) default NULL, -- name for this definition
1808 `description` text, -- description for this definition
1809 `date_created` datetime default NULL, -- date and time this definition was created
1810 `date_modified` datetime default NULL, -- date and time this definition was last modified
1811 `saved_sql` text, -- SQL snippet for us in reports
1812 report_area varchar(6) DEFAULT NULL, -- Koha module this definition is for Circulation, Catalog, Patrons, Acquistions, Accounts)
1814 KEY dictionary_area_idx (report_area)
1815 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1818 -- Table structure for table `reserves`
1821 DROP TABLE IF EXISTS `reserves`;
1822 CREATE TABLE `reserves` ( -- information related to holds/reserves in Koha
1823 `reserve_id` int(11) NOT NULL auto_increment, -- primary key
1824 `borrowernumber` int(11) NOT NULL default 0, -- foreign key from the borrowers table defining which patron this hold is for
1825 `reservedate` date default NULL, -- the date the hold was places
1826 `biblionumber` int(11) NOT NULL default 0, -- foreign key from the biblio table defining which bib record this hold is on
1827 `branchcode` varchar(10) default NULL, -- foreign key from the branches table defining which branch the patron wishes to pick this hold up at
1828 `notificationdate` date default NULL, -- currently unused
1829 `reminderdate` date default NULL, -- currently unused
1830 `cancellationdate` date default NULL, -- the date this hold was cancelled
1831 `reservenotes` mediumtext, -- notes related to this hold
1832 `priority` smallint(6) default NULL, -- where in the queue the patron sits
1833 `found` varchar(1) default NULL, -- a one letter code defining what the status is of the hold is after it has been confirmed
1834 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- the date and time this hold was last updated
1835 `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
1836 `waitingdate` date default NULL, -- the date the item was marked as waiting for the patron at the library
1837 `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)
1838 `lowestPriority` tinyint(1) NOT NULL,
1839 `suspend` BOOLEAN NOT NULL DEFAULT 0,
1840 `suspend_until` DATETIME NULL DEFAULT NULL,
1841 PRIMARY KEY (`reserve_id`),
1842 KEY priorityfoundidx (priority,found),
1843 KEY `borrowernumber` (`borrowernumber`),
1844 KEY `biblionumber` (`biblionumber`),
1845 KEY `itemnumber` (`itemnumber`),
1846 KEY `branchcode` (`branchcode`),
1847 CONSTRAINT `reserves_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE,
1848 CONSTRAINT `reserves_ibfk_2` FOREIGN KEY (`biblionumber`) REFERENCES `biblio` (`biblionumber`) ON DELETE CASCADE ON UPDATE CASCADE,
1849 CONSTRAINT `reserves_ibfk_3` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`) ON DELETE CASCADE ON UPDATE CASCADE,
1850 CONSTRAINT `reserves_ibfk_4` FOREIGN KEY (`branchcode`) REFERENCES `branches` (`branchcode`) ON DELETE CASCADE ON UPDATE CASCADE
1851 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1854 -- Table structure for table `reviews`
1857 DROP TABLE IF EXISTS `reviews`;
1858 CREATE TABLE `reviews` ( -- patron opac comments
1859 `reviewid` int(11) NOT NULL auto_increment, -- unique identifier for this comment
1860 `borrowernumber` int(11) default NULL, -- foreign key from the borrowers table defining which patron left this comment
1861 `biblionumber` int(11) default NULL, -- foreign key from the biblio table defining which bibliographic record this comment is for
1862 `review` text, -- the body of the comment
1863 `approved` tinyint(4) default NULL, -- whether this comment has been approved by a librarian (1 for yes, 0 for no)
1864 `datereviewed` datetime default NULL, -- the date the comment was left
1865 PRIMARY KEY (`reviewid`),
1866 CONSTRAINT `reviews_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE SET NULL ON UPDATE CASCADE,
1867 CONSTRAINT `reviews_ibfk_2` FOREIGN KEY (`biblionumber`) REFERENCES `biblio` (`biblionumber`) ON DELETE CASCADE ON UPDATE CASCADE
1868 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1871 -- Table structure for table `saved_sql`
1874 DROP TABLE IF EXISTS `saved_sql`;
1875 CREATE TABLE saved_sql ( -- saved sql reports
1876 `id` int(11) NOT NULL auto_increment, -- unique id and primary key assigned by Koha
1877 `borrowernumber` int(11) default NULL, -- the staff member who created this report (borrowers.borrowernumber)
1878 `date_created` datetime default NULL, -- the date this report was created
1879 `last_modified` datetime default NULL, -- the date this report was last edited
1880 `savedsql` text, -- the SQL for this report
1881 `last_run` datetime default NULL,
1882 `report_name` varchar(255) NOT NULL default '', -- the name of this report
1883 `type` varchar(255) default NULL, -- always 1 for tabular
1884 `notes` text, -- the notes or description given to this report
1885 `cache_expiry` int NOT NULL default 300,
1886 `public` boolean NOT NULL default FALSE,
1887 report_area varchar(6) default NULL,
1888 report_group varchar(80) default NULL,
1889 report_subgroup varchar(80) default NULL,
1891 KEY sql_area_group_idx (report_group, report_subgroup),
1892 KEY boridx (`borrowernumber`)
1893 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1897 -- Table structure for `saved_reports`
1900 DROP TABLE IF EXISTS `saved_reports`;
1901 CREATE TABLE saved_reports (
1902 `id` int(11) NOT NULL auto_increment,
1903 `report_id` int(11) default NULL,
1905 `date_run` datetime default NULL,
1907 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1911 -- Table structure for table `search_history`
1914 DROP TABLE IF EXISTS `search_history`;
1915 CREATE TABLE IF NOT EXISTS `search_history` ( -- patron's opac search history
1916 `id` int(11) NOT NULL auto_increment, -- search history id
1917 `userid` int(11) NOT NULL, -- the patron who performed the search (borrowers.borrowernumber)
1918 `sessionid` varchar(32) NOT NULL, -- a system generated session id
1919 `query_desc` varchar(255) NOT NULL, -- the search that was performed
1920 `query_cgi` text NOT NULL, -- the string to append to the search url to rerun the search
1921 `type` varchar(16) NOT NULL DEFAULT 'biblio', -- search type, must be 'biblio' or 'authority'
1922 `total` int(11) NOT NULL, -- the total of results found
1923 `time` timestamp NOT NULL default CURRENT_TIMESTAMP, -- the date and time the search was run
1924 KEY `userid` (`userid`),
1925 KEY `sessionid` (`sessionid`),
1927 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci COMMENT='Opac search history results';
1931 -- Table structure for table `serial`
1934 DROP TABLE IF EXISTS `serial`;
1935 CREATE TABLE `serial` ( -- issues related to subscriptions
1936 `serialid` int(11) NOT NULL auto_increment, -- unique key for the issue
1937 `biblionumber` varchar(100) NOT NULL default '', -- foreign key for the biblio.biblionumber that this issue is attached to
1938 `subscriptionid` varchar(100) NOT NULL default '', -- foreign key to the subscription.subscriptionid that this issue is part of
1939 `serialseq` varchar(100) NOT NULL default '', -- issue information (volume, number, etc)
1940 `status` tinyint(4) NOT NULL default 0, -- status code for this issue (see manual for full descriptions)
1941 `planneddate` date default NULL, -- date expected
1942 `notes` text, -- notes
1943 `publisheddate` date default NULL, -- date published
1944 `claimdate` date default NULL, -- date claimed
1945 claims_count int(11) default 0, -- number of claims made related to this issue
1946 `routingnotes` text, -- notes from the routing list
1947 PRIMARY KEY (`serialid`)
1948 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1951 -- Table structure for table `sessions`
1954 DROP TABLE IF EXISTS sessions;
1955 CREATE TABLE sessions (
1956 `id` varchar(32) NOT NULL,
1957 `a_session` mediumtext NOT NULL,
1959 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1962 -- Table structure for table `special_holidays`
1965 DROP TABLE IF EXISTS `special_holidays`;
1966 CREATE TABLE `special_holidays` ( -- non repeatable holidays/library closings
1967 `id` int(11) NOT NULL auto_increment, -- unique identifier assigned by Koha
1968 `branchcode` varchar(10) NOT NULL default '', -- foreign key from the branches table, defines which branch this closing is for
1969 `day` smallint(6) NOT NULL default 0, -- day of the month this closing is on
1970 `month` smallint(6) NOT NULL default 0, -- month this closing is in
1971 `year` smallint(6) NOT NULL default 0, -- year this closing is in
1972 `isexception` smallint(1) NOT NULL default 1, -- is this a holiday exception to a repeatable holiday (1 for yes, 0 for no)
1973 `title` varchar(50) NOT NULL default '', -- title for this closing
1974 `description` text NOT NULL, -- description of this closing
1976 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
1979 -- Table structure for table `statistics`
1982 DROP TABLE IF EXISTS `statistics`;
1983 CREATE TABLE `statistics` ( -- information related to transactions (circulation and fines) in Koha
1984 `datetime` datetime default NULL, -- date and time of the transaction
1985 `branch` varchar(10) default NULL, -- foreign key, branch where the transaction occurred
1986 `proccode` varchar(4) default NULL, -- type of procedure used when making payments (does not appear in the code)
1987 `value` double(16,4) default NULL, -- monetary value associated with the transaction
1988 `type` varchar(16) default NULL, -- transaction type (locause, issue, return, renew, writeoff, payment, Credit*)
1989 `other` mediumtext, -- used by SIP
1990 `usercode` varchar(10) default NULL, -- unused in Koha
1991 `itemnumber` int(11) default NULL, -- foreign key from the items table, links transaction to a specific item
1992 `itemtype` varchar(10) default NULL, -- foreign key from the itemtypes table, links transaction to a specific item type
1993 `borrowernumber` int(11) default NULL, -- foreign key from the borrowers table, links transaction to a specific borrower
1994 `associatedborrower` int(11) default NULL, -- unused in Koha
1995 `ccode` varchar(10) default NULL, -- foreign key from the items table, links transaction to a specific collection code
1996 KEY `timeidx` (`datetime`),
1997 KEY `branch_idx` (`branch`),
1998 KEY `proccode_idx` (`proccode`),
1999 KEY `type_idx` (`type`),
2000 KEY `usercode_idx` (`usercode`),
2001 KEY `itemnumber_idx` (`itemnumber`),
2002 KEY `itemtype_idx` (`itemtype`),
2003 KEY `borrowernumber_idx` (`borrowernumber`),
2004 KEY `associatedborrower_idx` (`associatedborrower`),
2005 KEY `ccode_idx` (`ccode`)
2006 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2009 -- Table structure for table `stopwords`
2012 DROP TABLE IF EXISTS `stopwords`;
2013 CREATE TABLE `stopwords` (
2014 `word` varchar(255) default NULL
2015 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2018 -- Table structure for table subscription_frequencies
2021 DROP TABLE IF EXISTS subscription_frequencies;
2022 CREATE TABLE subscription_frequencies (
2023 id INTEGER NOT NULL AUTO_INCREMENT,
2024 description TEXT NOT NULL,
2025 displayorder INT DEFAULT NULL,
2026 unit ENUM('day','week','month','year') DEFAULT NULL,
2027 unitsperissue INTEGER NOT NULL DEFAULT '1',
2028 issuesperunit INTEGER NOT NULL DEFAULT '1',
2030 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2033 -- Table structure for table subscription_numberpatterns
2036 DROP TABLE IF EXISTS subscription_numberpatterns;
2037 CREATE TABLE subscription_numberpatterns (
2038 id INTEGER NOT NULL AUTO_INCREMENT,
2039 label VARCHAR(255) NOT NULL,
2040 displayorder INTEGER DEFAULT NULL,
2041 description TEXT NOT NULL,
2042 numberingmethod VARCHAR(255) NOT NULL,
2043 label1 VARCHAR(255) DEFAULT NULL,
2044 add1 INTEGER DEFAULT NULL,
2045 every1 INTEGER DEFAULT NULL,
2046 whenmorethan1 INTEGER DEFAULT NULL,
2047 setto1 INTEGER DEFAULT NULL,
2048 numbering1 VARCHAR(255) DEFAULT NULL,
2049 label2 VARCHAR(255) DEFAULT NULL,
2050 add2 INTEGER DEFAULT NULL,
2051 every2 INTEGER DEFAULT NULL,
2052 whenmorethan2 INTEGER DEFAULT NULL,
2053 setto2 INTEGER DEFAULT NULL,
2054 numbering2 VARCHAR(255) DEFAULT NULL,
2055 label3 VARCHAR(255) DEFAULT NULL,
2056 add3 INTEGER DEFAULT NULL,
2057 every3 INTEGER DEFAULT NULL,
2058 whenmorethan3 INTEGER DEFAULT NULL,
2059 setto3 INTEGER DEFAULT NULL,
2060 numbering3 VARCHAR(255) DEFAULT NULL,
2062 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2065 -- Table structure for table `subscription`
2068 DROP TABLE IF EXISTS `subscription`;
2069 CREATE TABLE `subscription` ( -- information related to the subscription
2070 `biblionumber` int(11) NOT NULL default 0, -- foreign key for biblio.biblionumber that this subscription is attached to
2071 `subscriptionid` int(11) NOT NULL auto_increment, -- unique key for this subscription
2072 `librarian` varchar(100) default '', -- the librarian's username from borrowers.userid
2073 `startdate` date default NULL, -- start date for this subscription
2074 `aqbooksellerid` int(11) default 0, -- foreign key for aqbooksellers.id to link to the vendor
2075 `cost` int(11) default 0,
2076 `aqbudgetid` int(11) default 0,
2077 `weeklength` int(11) default 0, -- subscription length in weeks (will not be filled in if monthlength or numberlength is set)
2078 `monthlength` int(11) default 0, -- subscription length in weeks (will not be filled in if weeklength or numberlength is set)
2079 `numberlength` int(11) default 0, -- subscription length in weeks (will not be filled in if monthlength or weeklength is set)
2080 `periodicity` integer default null, -- frequency type links to subscription_frequencies.id
2081 countissuesperunit INTEGER NOT NULL DEFAULT 1,
2082 `notes` mediumtext, -- notes
2083 `status` varchar(100) NOT NULL default '', -- status of this subscription
2084 `lastvalue1` int(11) default NULL,
2085 `innerloop1` int(11) default 0,
2086 `lastvalue2` int(11) default NULL,
2087 `innerloop2` int(11) default 0,
2088 `lastvalue3` int(11) default NULL,
2089 `innerloop3` int(11) default 0,
2090 `firstacquidate` date default NULL, -- first issue received date
2091 `manualhistory` tinyint(1) NOT NULL default 0, -- yes or no to managing the history manually
2092 `irregularity` text, -- any irregularities in the subscription
2093 skip_serialseq BOOLEAN NOT NULL DEFAULT 0,
2094 `letter` varchar(20) default NULL,
2095 `numberpattern` integer default null, -- the numbering pattern used links to subscription_numberpatterns.id
2096 locale VARCHAR(80) DEFAULT NULL, -- for foreign language subscriptions to display months, seasons, etc correctly
2097 `distributedto` text,
2098 `internalnotes` longtext,
2099 `callnumber` text, -- default call number
2100 `location` varchar(80) NULL default '', -- default shelving location (items.location)
2101 `branchcode` varchar(10) NOT NULL default '', -- default branches (items.homebranch)
2102 `lastbranch` varchar(10),
2103 `serialsadditems` tinyint(1) NOT NULL default '0', -- does receiving this serial create an item record
2104 `staffdisplaycount` VARCHAR(10) NULL, -- how many issues to show to the staff
2105 `opacdisplaycount` VARCHAR(10) NULL, -- how many issues to show to the public
2106 `graceperiod` int(11) NOT NULL default '0', -- grace period in days
2107 `enddate` date default NULL, -- subscription end date
2108 `closed` INT(1) NOT NULL DEFAULT 0, -- yes / no if the subscription is closed
2109 `reneweddate` date default NULL, -- date of last renewal for the subscription
2110 PRIMARY KEY (`subscriptionid`),
2111 CONSTRAINT subscription_ibfk_1 FOREIGN KEY (periodicity) REFERENCES subscription_frequencies (id) ON DELETE SET NULL ON UPDATE CASCADE,
2112 CONSTRAINT subscription_ibfk_2 FOREIGN KEY (numberpattern) REFERENCES subscription_numberpatterns (id) ON DELETE SET NULL ON UPDATE CASCADE
2113 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2116 -- Table structure for table `subscriptionhistory`
2119 DROP TABLE IF EXISTS `subscriptionhistory`;
2120 CREATE TABLE `subscriptionhistory` (
2121 `biblionumber` int(11) NOT NULL default 0,
2122 `subscriptionid` int(11) NOT NULL default 0,
2123 `histstartdate` date default NULL,
2124 `histenddate` date default NULL,
2125 `missinglist` longtext NOT NULL,
2126 `recievedlist` longtext NOT NULL,
2127 `opacnote` varchar(150) NOT NULL default '',
2128 `librariannote` varchar(150) NOT NULL default '',
2129 PRIMARY KEY (`subscriptionid`),
2130 KEY `biblionumber` (`biblionumber`)
2131 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2134 -- Table structure for table `subscriptionroutinglist`
2137 DROP TABLE IF EXISTS `subscriptionroutinglist`;
2138 CREATE TABLE `subscriptionroutinglist` ( -- information related to the routing lists attached to subscriptions
2139 `routingid` int(11) NOT NULL auto_increment, -- unique identifier assigned by Koha
2140 `borrowernumber` int(11) NOT NULL, -- foreign key from the borrowers table, defines with patron is on the routing list
2141 `ranking` int(11) default NULL, -- where the patron stands in line to receive the serial
2142 `subscriptionid` int(11) NOT NULL, -- foreign key from the subscription table, defines which subscription this routing list is for
2143 PRIMARY KEY (`routingid`),
2144 UNIQUE (`subscriptionid`, `borrowernumber`),
2145 CONSTRAINT `subscriptionroutinglist_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`)
2146 ON DELETE CASCADE ON UPDATE CASCADE,
2147 CONSTRAINT `subscriptionroutinglist_ibfk_2` FOREIGN KEY (`subscriptionid`) REFERENCES `subscription` (`subscriptionid`)
2148 ON DELETE CASCADE ON UPDATE CASCADE
2149 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2152 -- Table structure for table `suggestions`
2155 DROP TABLE IF EXISTS `suggestions`;
2156 CREATE TABLE `suggestions` ( -- purchase suggestions
2157 `suggestionid` int(8) NOT NULL auto_increment, -- unique identifier assigned automatically by Koha
2158 `suggestedby` int(11) NOT NULL default 0, -- borrowernumber for the person making the suggestion, foreign key linking to the borrowers table
2159 `suggesteddate` date NOT NULL, -- date the suggestion was submitted
2160 `managedby` int(11) default NULL, -- borrowernumber for the librarian managing the suggestion, foreign key linking to the borrowers table
2161 `manageddate` date default NULL, -- date the suggestion was updated
2162 acceptedby INT(11) default NULL, -- borrowernumber for the librarian who accepted the suggestion, foreign key linking to the borrowers table
2163 accepteddate date default NULL, -- date the suggestion was marked as accepted
2164 rejectedby INT(11) default NULL, -- borrowernumber for the librarian who rejected the suggestion, foreign key linking to the borrowers table
2165 rejecteddate date default NULL, -- date the suggestion was marked as rejected
2166 `STATUS` varchar(10) NOT NULL default '', -- suggestion status (ASKED, CHECKED, ACCEPTED, or REJECTED)
2167 `note` mediumtext, -- note entered on the suggestion
2168 `author` varchar(80) default NULL, -- author of the suggested item
2169 `title` varchar(255) default NULL, -- title of the suggested item
2170 `copyrightdate` smallint(6) default NULL, -- copyright date of the suggested item
2171 `publishercode` varchar(255) default NULL, -- publisher of the suggested item
2172 `date` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- date and time the suggestion was updated
2173 `volumedesc` varchar(255) default NULL,
2174 `publicationyear` smallint(6) default 0,
2175 `place` varchar(255) default NULL, -- publication place of the suggested item
2176 `isbn` varchar(30) default NULL, -- isbn of the suggested item
2177 `biblionumber` int(11) default NULL, -- foreign key linking the suggestion to the biblio table after the suggestion has been ordered
2178 `reason` text, -- reason for accepting or rejecting the suggestion
2179 `patronreason` text, -- reason for making the suggestion
2180 budgetid INT(11), -- foreign key linking the suggested budget to the aqbudgets table
2181 branchcode VARCHAR(10) default NULL, -- foreign key linking the suggested branch to the branches table
2182 collectiontitle text default NULL, -- collection name for the suggested item
2183 itemtype VARCHAR(30) default NULL, -- suggested item type
2184 quantity SMALLINT(6) default NULL, -- suggested quantity to be purchased
2185 currency VARCHAR(3) default NULL, -- suggested currency for the suggested price
2186 price DECIMAL(28,6) default NULL, -- suggested price
2187 total DECIMAL(28,6) default NULL, -- suggested total cost (price*quantity updated for currency)
2188 PRIMARY KEY (`suggestionid`),
2189 KEY `suggestedby` (`suggestedby`),
2190 KEY `managedby` (`managedby`),
2191 KEY `status` (`STATUS`),
2192 KEY `biblionumber` (`biblionumber`),
2193 KEY `branchcode` (`branchcode`),
2194 CONSTRAINT `suggestions_budget_id_fk` FOREIGN KEY (`budgetid`) REFERENCES `aqbudgets` (`budget_id`) ON DELETE SET NULL ON UPDATE CASCADE
2195 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2198 -- Table structure for table `systempreferences`
2201 DROP TABLE IF EXISTS `systempreferences`;
2202 CREATE TABLE `systempreferences` ( -- global system preferences
2203 `variable` varchar(50) NOT NULL default '', -- system preference name
2204 `value` text, -- system preference values
2205 `options` mediumtext, -- options for multiple choice system preferences
2206 `explanation` text, -- descriptive text for the system preference
2207 `type` varchar(20) default NULL, -- type of question this preference asks (multiple choice, plain text, yes or no, etc)
2208 PRIMARY KEY (`variable`)
2209 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2212 -- Table structure for table `tags`
2215 DROP TABLE IF EXISTS `tags`;
2216 CREATE TABLE `tags` (
2217 `entry` varchar(255) NOT NULL default '',
2218 `weight` bigint(20) NOT NULL default 0,
2219 PRIMARY KEY (`entry`)
2220 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2223 -- Table structure for table `tags_all`
2226 DROP TABLE IF EXISTS `tags_all`;
2227 CREATE TABLE `tags_all` ( -- all of the tags
2228 `tag_id` int(11) NOT NULL auto_increment, -- unique id and primary key
2229 `borrowernumber` int(11) NOT NULL, -- the patron who added the tag (borrowers.borrowernumber)
2230 `biblionumber` int(11) NOT NULL, -- the bib record this tag was left on (biblio.biblionumber)
2231 `term` varchar(255) NOT NULL, -- the tag
2232 `language` int(4) default NULL, -- the language the tag was left in
2233 `date_created` datetime NOT NULL, -- the date the tag was added
2234 PRIMARY KEY (`tag_id`),
2235 KEY `tags_borrowers_fk_1` (`borrowernumber`),
2236 KEY `tags_biblionumber_fk_1` (`biblionumber`),
2237 CONSTRAINT `tags_borrowers_fk_1` FOREIGN KEY (`borrowernumber`)
2238 REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE,
2239 CONSTRAINT `tags_biblionumber_fk_1` FOREIGN KEY (`biblionumber`)
2240 REFERENCES `biblio` (`biblionumber`) ON DELETE CASCADE ON UPDATE CASCADE
2241 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2244 -- Table structure for table `tags_approval`
2247 DROP TABLE IF EXISTS `tags_approval`;
2248 CREATE TABLE `tags_approval` ( -- approved tags
2249 `term` varchar(255) NOT NULL, -- the tag
2250 `approved` int(1) NOT NULL default '0', -- whether the tag is approved or not (1=yes, 0=pending, -1=rejected)
2251 `date_approved` datetime default NULL, -- the date this tag was approved
2252 `approved_by` int(11) default NULL, -- the librarian who approved the tag (borrowers.borrowernumber)
2253 `weight_total` int(9) NOT NULL default '1', -- the total number of times this tag was used
2254 PRIMARY KEY (`term`),
2255 KEY `tags_approval_borrowers_fk_1` (`approved_by`),
2256 CONSTRAINT `tags_approval_borrowers_fk_1` FOREIGN KEY (`approved_by`)
2257 REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE
2258 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2261 -- Table structure for table `tags_index`
2264 DROP TABLE IF EXISTS `tags_index`;
2265 CREATE TABLE `tags_index` ( -- a weighted list of all tags and where they are used
2266 `term` varchar(255) NOT NULL, -- the tag
2267 `biblionumber` int(11) NOT NULL, -- the bib record this tag was used on (biblio.biblionumber)
2268 `weight` int(9) NOT NULL default '1', -- the number of times this term was used on this bib record
2269 PRIMARY KEY (`term`,`biblionumber`),
2270 KEY `tags_index_biblionumber_fk_1` (`biblionumber`),
2271 CONSTRAINT `tags_index_term_fk_1` FOREIGN KEY (`term`)
2272 REFERENCES `tags_approval` (`term`) ON DELETE CASCADE ON UPDATE CASCADE,
2273 CONSTRAINT `tags_index_biblionumber_fk_1` FOREIGN KEY (`biblionumber`)
2274 REFERENCES `biblio` (`biblionumber`) ON DELETE CASCADE ON UPDATE CASCADE
2275 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2278 -- Table structure for table `userflags`
2281 DROP TABLE IF EXISTS `userflags`;
2282 CREATE TABLE `userflags` (
2283 `bit` int(11) NOT NULL default 0,
2284 `flag` varchar(30) default NULL,
2285 `flagdesc` varchar(255) default NULL,
2286 `defaulton` int(11) default NULL,
2288 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2291 -- Table structure for table `virtualshelves`
2294 DROP TABLE IF EXISTS `virtualshelves`;
2295 CREATE TABLE `virtualshelves` ( -- information about lists (or virtual shelves)
2296 `shelfnumber` int(11) NOT NULL auto_increment, -- unique identifier assigned by Koha
2297 `shelfname` varchar(255) default NULL, -- name of the list
2298 `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)
2299 `category` varchar(1) default NULL, -- type of list (private [1], public [2])
2300 `sortfield` varchar(16) default NULL, -- the field this list is sorted on
2301 `lastmodified` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- date and time the list was last modified
2302 `created_on` TIMESTAMP NOT NULL, -- creation time
2303 `allow_add` tinyint(1) default 0, -- permission for adding entries to list
2304 `allow_delete_own` tinyint(1) default 1, -- permission for deleting entries frm list that you added yourself
2305 `allow_delete_other` tinyint(1) default 0, -- permission for deleting entries from list that another person added
2306 PRIMARY KEY (`shelfnumber`),
2307 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
2308 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2311 -- Table structure for table `virtualshelfcontents`
2314 DROP TABLE IF EXISTS `virtualshelfcontents`;
2315 CREATE TABLE `virtualshelfcontents` ( -- information about the titles in a list (or virtual shelf)
2316 `shelfnumber` int(11) NOT NULL default 0, -- foreign key linking to the virtualshelves table, defines the list that this record has been added to
2317 `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
2318 `flags` int(11) default NULL,
2319 `dateadded` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, -- date and time this bib record was added to the list
2320 `borrowernumber` int, -- borrower number that created this list entry (only the first one is saved: no need for use in/as key)
2321 KEY `shelfnumber` (`shelfnumber`),
2322 KEY `biblionumber` (`biblionumber`),
2323 CONSTRAINT `virtualshelfcontents_ibfk_1` FOREIGN KEY (`shelfnumber`) REFERENCES `virtualshelves` (`shelfnumber`) ON DELETE CASCADE ON UPDATE CASCADE,
2324 CONSTRAINT `shelfcontents_ibfk_2` FOREIGN KEY (`biblionumber`) REFERENCES `biblio` (`biblionumber`) ON DELETE CASCADE ON UPDATE CASCADE,
2325 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
2326 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2329 -- Table structure for table `virtualshelfshares`
2332 DROP TABLE IF EXISTS `virtualshelfshares`;
2333 CREATE TABLE `virtualshelfshares` ( -- shared private lists
2334 `id` int AUTO_INCREMENT PRIMARY KEY, -- unique key
2335 `shelfnumber` int NOT NULL, -- foreign key for virtualshelves
2336 `borrowernumber` int, -- borrower that accepted access to this list
2337 `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
2338 `sharedate` datetime, -- date of invitation or acceptance of invitation
2339 CONSTRAINT `virtualshelfshares_ibfk_1` FOREIGN KEY (`shelfnumber`) REFERENCES `virtualshelves` (`shelfnumber`) ON DELETE CASCADE ON UPDATE CASCADE,
2340 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
2341 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2344 -- Table structure for table `z3950servers`
2347 DROP TABLE IF EXISTS `z3950servers`;
2348 CREATE TABLE `z3950servers` ( -- connection information for the Z39.50 targets used in cataloging
2349 `id` int(11) NOT NULL auto_increment, -- unique identifier assigned by Koha
2350 `host` varchar(255) default NULL, -- target's host name
2351 `port` int(11) default NULL, -- port number used to connect to target
2352 `db` varchar(255) default NULL, -- target's database name
2353 `userid` varchar(255) default NULL, -- username needed to log in to target
2354 `password` varchar(255) default NULL, -- password needed to log in to target
2355 `servername` mediumtext NOT NULL, -- name given to the target by the library
2356 `checked` smallint(6) default NULL, -- whether this target is checked by default (1 for yes, 0 for no)
2357 `rank` int(11) default NULL, -- where this target appears in the list of targets
2358 `syntax` varchar(80) default NULL, -- marc format provided by this target
2359 `timeout` int(11) NOT NULL DEFAULT '0', -- number of seconds before Koha stops trying to access this server
2360 `servertype` enum('zed','sru') NOT NULL default 'zed', -- zed means z39.50 server
2361 `encoding` text default NULL, -- characters encoding provided by this target
2362 `recordtype` enum('authority','biblio') NOT NULL default 'biblio', -- server contains bibliographic or authority records
2363 `sru_options` varchar(255) default NULL, -- options like sru=get, sru_version=1.1; will be passed to the server via ZOOM
2364 `sru_fields` mediumtext default NULL, -- contains the mapping between the Z3950 search fields and the specific SRU server indexes
2365 `add_xslt` mediumtext default NULL, -- zero or more paths to XSLT files to be processed on the search results
2367 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2370 -- Table structure for table `zebraqueue`
2373 DROP TABLE IF EXISTS `zebraqueue`;
2374 CREATE TABLE `zebraqueue` (
2375 `id` int(11) NOT NULL auto_increment,
2376 `biblio_auth_number` bigint(20) unsigned NOT NULL default '0',
2377 `operation` char(20) NOT NULL default '',
2378 `server` char(20) NOT NULL default '',
2379 `done` int(11) NOT NULL default '0',
2380 `time` timestamp NOT NULL default CURRENT_TIMESTAMP,
2382 KEY `zebraqueue_lookup` (`server`, `biblio_auth_number`, `operation`, `done`)
2383 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2386 -- Table structure for table `services_throttle`
2389 DROP TABLE IF EXISTS `services_throttle`;
2390 CREATE TABLE `services_throttle` (
2391 `service_type` varchar(10) NOT NULL default '',
2392 `service_count` varchar(45) default NULL,
2393 PRIMARY KEY (`service_type`)
2394 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2397 -- Table structure for table `language_subtag_registry`
2398 -- http://www.w3.org/International/articles/language-tags/
2402 DROP TABLE IF EXISTS language_subtag_registry;
2403 CREATE TABLE language_subtag_registry (
2405 type varchar(25), -- language-script-region-variant-extension-privateuse
2406 description varchar(25), -- only one of the possible descriptions for ease of reference, see language_descriptions for the complete list
2408 id int(11) NOT NULL auto_increment,
2410 KEY `subtag` (`subtag`)
2411 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2414 -- Table structure for table `language_rfc4646_to_iso639`
2415 -- TODO: add suppress_scripts
2416 -- this maps three letter codes defined in iso639.2 back to their
2417 -- two letter equivilents in rfc4646 (LOC maintains iso639+)
2420 DROP TABLE IF EXISTS language_rfc4646_to_iso639;
2421 CREATE TABLE language_rfc4646_to_iso639 (
2422 rfc4646_subtag varchar(25),
2423 iso639_2_code varchar(25),
2424 id int(11) NOT NULL auto_increment,
2426 KEY `rfc4646_subtag` (`rfc4646_subtag`)
2427 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2430 -- Table structure for table `language_descriptions`
2433 DROP TABLE IF EXISTS language_descriptions;
2434 CREATE TABLE language_descriptions (
2438 description varchar(255),
2439 id int(11) NOT NULL auto_increment,
2441 KEY `lang` (`lang`),
2442 KEY `subtag_type_lang` (`subtag`, `type`, `lang`)
2443 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2446 -- Table structure for table `language_script_bidi`
2447 -- bi-directional support, keyed by script subcode
2450 DROP TABLE IF EXISTS language_script_bidi;
2451 CREATE TABLE language_script_bidi (
2452 rfc4646_subtag varchar(25), -- script subtag, Arab, Hebr, etc.
2453 bidi varchar(3), -- rtl ltr
2454 KEY `rfc4646_subtag` (`rfc4646_subtag`)
2455 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2458 -- Table structure for table `language_script_mapping`
2459 -- TODO: need to map language subtags to script subtags for detection
2460 -- of bidi when script is not specified (like ar, he)
2463 DROP TABLE IF EXISTS language_script_mapping;
2464 CREATE TABLE language_script_mapping (
2465 language_subtag varchar(25),
2466 script_subtag varchar(25),
2467 KEY `language_subtag` (`language_subtag`)
2468 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2471 -- Table structure for table `permissions`
2474 DROP TABLE IF EXISTS `permissions`;
2475 CREATE TABLE `permissions` (
2476 `module_bit` int(11) NOT NULL DEFAULT 0,
2477 `code` varchar(64) DEFAULT NULL,
2478 `description` varchar(255) DEFAULT NULL,
2479 PRIMARY KEY (`module_bit`, `code`),
2480 CONSTRAINT `permissions_ibfk_1` FOREIGN KEY (`module_bit`) REFERENCES `userflags` (`bit`)
2481 ON DELETE CASCADE ON UPDATE CASCADE
2482 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2485 -- Table structure for table `serialitems`
2488 DROP TABLE IF EXISTS `serialitems`;
2489 CREATE TABLE `serialitems` (
2490 `itemnumber` int(11) NOT NULL,
2491 `serialid` int(11) NOT NULL,
2492 UNIQUE KEY `serialitemsidx` (`itemnumber`),
2493 KEY `serialitems_sfk_1` (`serialid`),
2494 CONSTRAINT `serialitems_sfk_1` FOREIGN KEY (`serialid`) REFERENCES `serial` (`serialid`) ON DELETE CASCADE ON UPDATE CASCADE,
2495 CONSTRAINT `serialitems_sfk_2` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`) ON DELETE CASCADE ON UPDATE CASCADE
2496 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2499 -- Table structure for table `user_permissions`
2502 DROP TABLE IF EXISTS `user_permissions`;
2503 CREATE TABLE `user_permissions` (
2504 `borrowernumber` int(11) NOT NULL DEFAULT 0,
2505 `module_bit` int(11) NOT NULL DEFAULT 0,
2506 `code` varchar(64) DEFAULT NULL,
2507 CONSTRAINT `user_permissions_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`)
2508 ON DELETE CASCADE ON UPDATE CASCADE,
2509 CONSTRAINT `user_permissions_ibfk_2` FOREIGN KEY (`module_bit`, `code`) REFERENCES `permissions` (`module_bit`, `code`)
2510 ON DELETE CASCADE ON UPDATE CASCADE
2511 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2514 -- Table structure for table `tmp_holdsqueue`
2517 DROP TABLE IF EXISTS `tmp_holdsqueue`;
2518 CREATE TABLE `tmp_holdsqueue` (
2519 `biblionumber` int(11) default NULL,
2520 `itemnumber` int(11) default NULL,
2521 `barcode` varchar(20) default NULL,
2522 `surname` mediumtext NOT NULL,
2525 `borrowernumber` int(11) NOT NULL,
2526 `cardnumber` varchar(16) default NULL,
2527 `reservedate` date default NULL,
2529 `itemcallnumber` varchar(255) default NULL,
2530 `holdingbranch` varchar(10) default NULL,
2531 `pickbranch` varchar(10) default NULL,
2533 `item_level_request` tinyint(4) NOT NULL default 0
2534 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2537 -- Table structure for table `message_queue`
2540 DROP TABLE IF EXISTS `message_queue`;
2541 CREATE TABLE `message_queue` (
2542 `message_id` int(11) NOT NULL auto_increment,
2543 `borrowernumber` int(11) default NULL,
2546 `metadata` text DEFAULT NULL,
2547 `letter_code` varchar(64) DEFAULT NULL,
2548 `message_transport_type` varchar(20) NOT NULL,
2549 `status` enum('sent','pending','failed','deleted') NOT NULL default 'pending',
2550 `time_queued` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
2551 `to_address` mediumtext,
2552 `from_address` mediumtext,
2553 `content_type` text,
2554 PRIMARY KEY `message_id` (`message_id`),
2555 KEY `borrowernumber` (`borrowernumber`),
2556 KEY `message_transport_type` (`message_transport_type`),
2557 CONSTRAINT `messageq_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE,
2558 CONSTRAINT `messageq_ibfk_2` FOREIGN KEY (`message_transport_type`) REFERENCES `message_transport_types` (`message_transport_type`) ON DELETE RESTRICT ON UPDATE CASCADE
2559 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2562 -- Table structure for table `message_transport_types`
2565 DROP TABLE IF EXISTS `message_transport_types`;
2566 CREATE TABLE `message_transport_types` (
2567 `message_transport_type` varchar(20) NOT NULL,
2568 PRIMARY KEY (`message_transport_type`)
2569 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2572 -- Table structure for table `overduerules_transport_types`
2575 DROP TABLE IF EXISTS `overduerules_transport_types`;
2576 CREATE TABLE overduerules_transport_types(
2577 `id` INT(11) NOT NULL AUTO_INCREMENT,
2578 `branchcode` varchar(10) NOT NULL DEFAULT '',
2579 `categorycode` VARCHAR(10) NOT NULL DEFAULT '',
2580 `letternumber` INT(1) NOT NULL DEFAULT 1,
2581 `message_transport_type` VARCHAR(20) NOT NULL DEFAULT 'email',
2583 CONSTRAINT overduerules_fk FOREIGN KEY (branchcode, categorycode) REFERENCES overduerules (branchcode, categorycode) ON DELETE CASCADE ON UPDATE CASCADE,
2584 CONSTRAINT mtt_fk FOREIGN KEY (message_transport_type) REFERENCES message_transport_types (message_transport_type) ON DELETE CASCADE ON UPDATE CASCADE
2585 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2588 -- Table structure for table `message_attributes`
2591 DROP TABLE IF EXISTS `message_attributes`;
2592 CREATE TABLE `message_attributes` (
2593 `message_attribute_id` int(11) NOT NULL auto_increment,
2594 `message_name` varchar(40) NOT NULL default '',
2595 `takes_days` tinyint(1) NOT NULL default '0',
2596 PRIMARY KEY (`message_attribute_id`),
2597 UNIQUE KEY `message_name` (`message_name`)
2598 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2601 -- Table structure for table `message_transports`
2604 DROP TABLE IF EXISTS `message_transports`;
2605 CREATE TABLE `message_transports` (
2606 `message_attribute_id` int(11) NOT NULL,
2607 `message_transport_type` varchar(20) NOT NULL,
2608 `is_digest` tinyint(1) NOT NULL default '0',
2609 `letter_module` varchar(20) NOT NULL default '',
2610 `letter_code` varchar(20) NOT NULL default '',
2611 `branchcode` varchar(10) NOT NULL default '',
2612 PRIMARY KEY (`message_attribute_id`,`message_transport_type`,`is_digest`),
2613 KEY `message_transport_type` (`message_transport_type`),
2614 KEY `letter_module` (`letter_module`,`letter_code`),
2615 CONSTRAINT `message_transports_ibfk_1` FOREIGN KEY (`message_attribute_id`) REFERENCES `message_attributes` (`message_attribute_id`) ON DELETE CASCADE ON UPDATE CASCADE,
2616 CONSTRAINT `message_transports_ibfk_2` FOREIGN KEY (`message_transport_type`) REFERENCES `message_transport_types` (`message_transport_type`) ON DELETE CASCADE ON UPDATE CASCADE,
2617 CONSTRAINT `message_transports_ibfk_3` FOREIGN KEY (`letter_module`, `letter_code`, `branchcode`) REFERENCES `letter` (`module`, `code`, `branchcode`) ON DELETE CASCADE ON UPDATE CASCADE
2618 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2621 -- Table structure for table `borrower_files`
2624 DROP TABLE IF EXISTS `borrower_files`;
2625 CREATE TABLE IF NOT EXISTS `borrower_files` ( -- files attached to the patron/borrower record
2626 `file_id` int(11) NOT NULL AUTO_INCREMENT, -- unique key
2627 `borrowernumber` int(11) NOT NULL, -- foreign key linking to the patron via the borrowernumber
2628 `file_name` varchar(255) NOT NULL, -- file name
2629 `file_type` varchar(255) NOT NULL, -- type of file
2630 `file_description` varchar(255) DEFAULT NULL, -- description given to the file
2631 `file_content` longblob NOT NULL, -- the file
2632 `date_uploaded` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, -- date and time the file was added
2633 PRIMARY KEY (`file_id`),
2634 KEY `borrowernumber` (`borrowernumber`),
2635 CONSTRAINT borrower_files_ibfk_1 FOREIGN KEY (borrowernumber) REFERENCES borrowers (borrowernumber) ON DELETE CASCADE ON UPDATE CASCADE
2636 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2639 -- Table structure for table `borrower_message_preferences`
2642 DROP TABLE IF EXISTS `borrower_message_preferences`;
2643 CREATE TABLE `borrower_message_preferences` (
2644 `borrower_message_preference_id` int(11) NOT NULL auto_increment,
2645 `borrowernumber` int(11) default NULL,
2646 `categorycode` varchar(10) default NULL,
2647 `message_attribute_id` int(11) default '0',
2648 `days_in_advance` int(11) default '0',
2649 `wants_digest` tinyint(1) NOT NULL default '0',
2650 PRIMARY KEY (`borrower_message_preference_id`),
2651 KEY `borrowernumber` (`borrowernumber`),
2652 KEY `categorycode` (`categorycode`),
2653 KEY `message_attribute_id` (`message_attribute_id`),
2654 CONSTRAINT `borrower_message_preferences_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE,
2655 CONSTRAINT `borrower_message_preferences_ibfk_2` FOREIGN KEY (`message_attribute_id`) REFERENCES `message_attributes` (`message_attribute_id`) ON DELETE CASCADE ON UPDATE CASCADE,
2656 CONSTRAINT `borrower_message_preferences_ibfk_3` FOREIGN KEY (`categorycode`) REFERENCES `categories` (`categorycode`) ON DELETE CASCADE ON UPDATE CASCADE
2657 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2660 -- Table structure for table `borrower_message_transport_preferences`
2663 DROP TABLE IF EXISTS `borrower_message_transport_preferences`;
2664 CREATE TABLE `borrower_message_transport_preferences` (
2665 `borrower_message_preference_id` int(11) NOT NULL default '0',
2666 `message_transport_type` varchar(20) NOT NULL default '0',
2667 PRIMARY KEY (`borrower_message_preference_id`,`message_transport_type`),
2668 KEY `message_transport_type` (`message_transport_type`),
2669 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,
2670 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
2671 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2674 -- Table structure for the table branch_transfer_limits
2677 DROP TABLE IF EXISTS `branch_transfer_limits`;
2678 CREATE TABLE branch_transfer_limits (
2679 limitId int(8) NOT NULL auto_increment,
2680 toBranch varchar(10) NOT NULL,
2681 fromBranch varchar(10) NOT NULL,
2682 itemtype varchar(10) NULL,
2683 ccode varchar(10) NULL,
2684 PRIMARY KEY (limitId)
2685 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2688 -- Table structure for table `item_circulation_alert_preferences`
2691 DROP TABLE IF EXISTS `item_circulation_alert_preferences`;
2692 CREATE TABLE `item_circulation_alert_preferences` (
2693 `id` int(11) NOT NULL auto_increment,
2694 `branchcode` varchar(10) NOT NULL,
2695 `categorycode` varchar(10) NOT NULL,
2696 `item_type` varchar(10) NOT NULL,
2697 `notification` varchar(16) NOT NULL,
2699 KEY `branchcode` (`branchcode`,`categorycode`,`item_type`, `notification`)
2700 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2703 -- Table structure for table `messages`
2705 DROP TABLE IF EXISTS `messages`;
2706 CREATE TABLE `messages` ( -- circulation messages left via the patron's check out screen
2707 `message_id` int(11) NOT NULL auto_increment, -- unique identifier assigned by Koha
2708 `borrowernumber` int(11) NOT NULL, -- foreign key linking this message to the borrowers table
2709 `branchcode` varchar(10) default NULL, -- foreign key linking the message to the branches table
2710 `message_type` varchar(1) NOT NULL, -- whether the message is for the librarians (L) or the patron (B)
2711 `message` text NOT NULL, -- the text of the message
2712 `message_date` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, -- the date and time the message was written
2713 PRIMARY KEY (`message_id`)
2714 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2717 -- Table structure for table `accountlines`
2720 DROP TABLE IF EXISTS `accountlines`;
2721 CREATE TABLE `accountlines` (
2722 `accountlines_id` int(11) NOT NULL AUTO_INCREMENT,
2723 `borrowernumber` int(11) NOT NULL default 0,
2724 `accountno` smallint(6) NOT NULL default 0,
2725 `itemnumber` int(11) default NULL,
2726 `date` date default NULL,
2727 `amount` decimal(28,6) default NULL,
2728 `description` mediumtext,
2729 `dispute` mediumtext,
2730 `accounttype` varchar(5) default NULL,
2731 `amountoutstanding` decimal(28,6) default NULL,
2732 `lastincrement` decimal(28,6) default NULL,
2733 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
2734 `notify_id` int(11) NOT NULL default 0,
2735 `notify_level` int(2) NOT NULL default 0,
2736 `note` text NULL default NULL,
2737 `manager_id` int(11) NULL,
2738 PRIMARY KEY (`accountlines_id`),
2739 KEY `acctsborridx` (`borrowernumber`),
2740 KEY `timeidx` (`timestamp`),
2741 KEY `itemnumber` (`itemnumber`),
2742 CONSTRAINT `accountlines_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE,
2743 CONSTRAINT `accountlines_ibfk_2` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`) ON DELETE SET NULL ON UPDATE SET NULL
2744 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2747 -- Table structure for table `accountoffsets`
2750 DROP TABLE IF EXISTS `accountoffsets`;
2751 CREATE TABLE `accountoffsets` (
2752 `borrowernumber` int(11) NOT NULL default 0,
2753 `accountno` smallint(6) NOT NULL default 0,
2754 `offsetaccount` smallint(6) NOT NULL default 0,
2755 `offsetamount` decimal(28,6) default NULL,
2756 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
2757 CONSTRAINT `accountoffsets_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE CASCADE ON UPDATE CASCADE
2758 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2761 -- Table structure for table `action_logs`
2764 DROP TABLE IF EXISTS `action_logs`;
2765 CREATE TABLE `action_logs` ( -- logs of actions taken in Koha (requires that the logs be turned on)
2766 `action_id` int(11) NOT NULL auto_increment, -- unique identifier for each action
2767 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- the date and time the action took place
2768 `user` int(11) NOT NULL default 0, -- the staff member who performed the action (borrowers.borrowernumber)
2769 `module` text, -- the module this action was taken against
2770 `action` text, -- the action (includes things like DELETED, ADDED, MODIFY, etc)
2771 `object` int(11) default NULL, -- the object that the action was taken against (could be a borrowernumber, itemnumber, etc)
2772 `info` text, -- information about the action (usually includes SQL statement)
2773 PRIMARY KEY (`action_id`),
2774 KEY `timestamp_idx` (`timestamp`),
2775 KEY `user_idx` (`user`),
2776 KEY `module_idx` (`module`(255)),
2777 KEY `action_idx` (`action`(255)),
2778 KEY `object_idx` (`object`),
2779 KEY `info_idx` (`info`(255))
2780 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2783 -- Table structure for table `alert`
2786 DROP TABLE IF EXISTS `alert`;
2787 CREATE TABLE `alert` (
2788 `alertid` int(11) NOT NULL auto_increment,
2789 `borrowernumber` int(11) NOT NULL default 0,
2790 `type` varchar(10) NOT NULL default '',
2791 `externalid` varchar(20) NOT NULL default '',
2792 PRIMARY KEY (`alertid`),
2793 KEY `borrowernumber` (`borrowernumber`),
2794 KEY `type` (`type`,`externalid`)
2795 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2798 -- Table structure for table `aqbasketgroups`
2801 DROP TABLE IF EXISTS `aqbasketgroups`;
2802 CREATE TABLE `aqbasketgroups` (
2803 `id` int(11) NOT NULL auto_increment,
2804 `name` varchar(50) default NULL,
2805 `closed` tinyint(1) default NULL,
2806 `booksellerid` int(11) NOT NULL,
2807 `deliveryplace` varchar(10) default NULL,
2808 `freedeliveryplace` text default NULL,
2809 `deliverycomment` varchar(255) default NULL,
2810 `billingplace` varchar(10) default NULL,
2812 KEY `booksellerid` (`booksellerid`),
2813 CONSTRAINT `aqbasketgroups_ibfk_1` FOREIGN KEY (`booksellerid`) REFERENCES `aqbooksellers` (`id`) ON UPDATE CASCADE ON DELETE CASCADE
2814 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2817 -- Table structure for table `aqbasket`
2820 DROP TABLE IF EXISTS `aqbasket`;
2821 CREATE TABLE `aqbasket` ( -- stores data about baskets in acquisitions
2822 `basketno` int(11) NOT NULL auto_increment, -- primary key, Koha defined number
2823 `basketname` varchar(50) default NULL, -- name given to the basket at creation
2824 `note` mediumtext, -- the internal note added at basket creation
2825 `booksellernote` mediumtext, -- the vendor note added at basket creation
2826 `contractnumber` int(11), -- links this basket to the aqcontract table (aqcontract.contractnumber)
2827 `creationdate` date default NULL, -- the date the basket was created
2828 `closedate` date default NULL, -- the date the basket was closed
2829 `booksellerid` int(11) NOT NULL default 1, -- the Koha assigned ID for the vendor (aqbooksellers.id)
2830 `authorisedby` varchar(10) default NULL, -- the borrowernumber of the person who created the basket
2831 `booksellerinvoicenumber` mediumtext, -- appears to always be NULL
2832 `basketgroupid` int(11), -- links this basket to its group (aqbasketgroups.id)
2833 `deliveryplace` varchar(10) default NULL, -- basket delivery place
2834 `billingplace` varchar(10) default NULL, -- basket billing place
2835 branch varchar(10) default NULL, -- basket branch
2836 PRIMARY KEY (`basketno`),
2837 KEY `booksellerid` (`booksellerid`),
2838 KEY `basketgroupid` (`basketgroupid`),
2839 KEY `contractnumber` (`contractnumber`),
2840 KEY `authorisedby` (`authorisedby`),
2841 CONSTRAINT `aqbasket_ibfk_1` FOREIGN KEY (`booksellerid`) REFERENCES `aqbooksellers` (`id`) ON UPDATE CASCADE,
2842 CONSTRAINT `aqbasket_ibfk_2` FOREIGN KEY (`contractnumber`) REFERENCES `aqcontract` (`contractnumber`),
2843 CONSTRAINT `aqbasket_ibfk_3` FOREIGN KEY (`basketgroupid`) REFERENCES `aqbasketgroups` (`id`) ON UPDATE CASCADE,
2844 CONSTRAINT aqbasket_ibfk_4 FOREIGN KEY (branch) REFERENCES branches (branchcode) ON UPDATE CASCADE ON DELETE SET NULL
2845 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2848 -- Table structure for table aqbasketusers
2851 DROP TABLE IF EXISTS aqbasketusers;
2852 CREATE TABLE aqbasketusers (
2853 basketno int(11) NOT NULL,
2854 borrowernumber int(11) NOT NULL,
2855 PRIMARY KEY (basketno,borrowernumber),
2856 CONSTRAINT aqbasketusers_ibfk_1 FOREIGN KEY (basketno) REFERENCES aqbasket (basketno) ON UPDATE CASCADE ON DELETE CASCADE,
2857 CONSTRAINT aqbasketusers_ibfk_2 FOREIGN KEY (borrowernumber) REFERENCES borrowers (borrowernumber) ON UPDATE CASCADE ON DELETE CASCADE
2858 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2861 -- Table structure for table `aqbooksellers`
2864 DROP TABLE IF EXISTS `aqbooksellers`;
2865 CREATE TABLE `aqbooksellers` ( -- information about the vendors listed in acquisitions
2866 `id` int(11) NOT NULL auto_increment, -- primary key and unique identifier assigned by Koha
2867 `name` mediumtext NOT NULL, -- vendor name
2868 `address1` mediumtext, -- first line of vendor physical address
2869 `address2` mediumtext, -- second line of vendor physical address
2870 `address3` mediumtext, -- third line of vendor physical address
2871 `address4` mediumtext, -- fourth line of vendor physical address
2872 `phone` varchar(30) default NULL, -- vendor phone number
2873 `accountnumber` mediumtext, -- unused in Koha
2874 `othersupplier` mediumtext, -- unused in Koha
2875 `currency` varchar(3) NOT NULL default '', -- unused in Koha
2876 `booksellerfax` mediumtext, -- vendor fax number
2877 `notes` mediumtext, -- order notes
2878 `bookselleremail` mediumtext, -- vendor email
2879 `booksellerurl` mediumtext, -- unused in Koha
2880 `postal` mediumtext, -- vendor postal address (all lines)
2881 `url` varchar(255) default NULL, -- vendor web address
2882 `active` tinyint(4) default NULL, -- is this vendor active (1 for yes, 0 for no)
2883 `listprice` varchar(10) default NULL, -- currency code for list prices
2884 `invoiceprice` varchar(10) default NULL, -- currency code for invoice prices
2885 `gstreg` tinyint(4) default NULL, -- is your library charged tax (1 for yes, 0 for no)
2886 `listincgst` tinyint(4) default NULL, -- is tax included in list prices (1 for yes, 0 for no)
2887 `invoiceincgst` tinyint(4) default NULL, -- is tax included in invoice prices (1 for yes, 0 for no)
2888 `gstrate` decimal(6,4) default NULL, -- the tax rate the library is charged
2889 `discount` float(6,4) default NULL, -- discount offered on all items ordered from this vendor
2890 `fax` varchar(50) default NULL, -- vendor fax number
2891 deliverytime int(11) default NULL, -- vendor delivery time
2893 KEY `listprice` (`listprice`),
2894 KEY `invoiceprice` (`invoiceprice`),
2895 KEY `name` (`name`(255)),
2896 CONSTRAINT `aqbooksellers_ibfk_1` FOREIGN KEY (`listprice`) REFERENCES `currency` (`currency`) ON DELETE CASCADE ON UPDATE CASCADE,
2897 CONSTRAINT `aqbooksellers_ibfk_2` FOREIGN KEY (`invoiceprice`) REFERENCES `currency` (`currency`) ON DELETE CASCADE ON UPDATE CASCADE
2898 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2901 -- Table structure for table `aqbudgets`
2904 DROP TABLE IF EXISTS `aqbudgets`;
2905 CREATE TABLE `aqbudgets` ( -- information related to Funds
2906 `budget_id` int(11) NOT NULL auto_increment, -- primary key and unique number assigned to each fund by Koha
2907 `budget_parent_id` int(11) default NULL, -- if this fund is a child of another this will include the parent id (aqbudgets.budget_id)
2908 `budget_code` varchar(30) default NULL, -- code assigned to the fund by the user
2909 `budget_name` varchar(80) default NULL, -- name assigned to the fund by the user
2910 `budget_branchcode` varchar(10) default NULL, -- branch that this fund belongs to (branches.branchcode)
2911 `budget_amount` decimal(28,6) NULL default '0.00', -- total amount for this fund
2912 `budget_encumb` decimal(28,6) NULL default '0.00', -- not used in the code
2913 `budget_expend` decimal(28,6) NULL default '0.00', -- not used in the code
2914 `budget_notes` mediumtext, -- notes related to this fund
2915 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- date and time this fund was last touched (created or modified)
2916 `budget_period_id` int(11) default NULL, -- id of the budget that this fund belongs to (aqbudgetperiods.budget_period_id)
2917 `sort1_authcat` varchar(80) default NULL, -- statistical category for this fund
2918 `sort2_authcat` varchar(80) default NULL, -- second statistical category for this fund
2919 `budget_owner_id` int(11) default NULL, -- borrowernumber of the person who owns this fund (borrowers.borrowernumber)
2920 `budget_permission` int(1) default '0', -- level of permission for this fund (used only by the owner, only by the library, or anyone)
2921 PRIMARY KEY (`budget_id`),
2922 KEY `budget_parent_id` (`budget_parent_id`),
2923 KEY `budget_code` (`budget_code`),
2924 KEY `budget_branchcode` (`budget_branchcode`),
2925 KEY `budget_period_id` (`budget_period_id`),
2926 KEY `budget_owner_id` (`budget_owner_id`)
2927 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2930 -- Table structure for table aqbudgetborrowers
2933 DROP TABLE IF EXISTS aqbudgetborrowers;
2934 CREATE TABLE aqbudgetborrowers (
2935 budget_id int(11) NOT NULL,
2936 borrowernumber int(11) NOT NULL,
2937 PRIMARY KEY (budget_id, borrowernumber),
2938 CONSTRAINT aqbudgetborrowers_ibfk_1 FOREIGN KEY (budget_id)
2939 REFERENCES aqbudgets (budget_id)
2940 ON DELETE CASCADE ON UPDATE CASCADE,
2941 CONSTRAINT aqbudgetborrowers_ibfk_2 FOREIGN KEY (borrowernumber)
2942 REFERENCES borrowers (borrowernumber)
2943 ON DELETE CASCADE ON UPDATE CASCADE
2944 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2947 -- Table structure for table `aqbudgetperiods`
2951 DROP TABLE IF EXISTS `aqbudgetperiods`;
2952 CREATE TABLE `aqbudgetperiods` ( -- information related to Budgets
2953 `budget_period_id` int(11) NOT NULL auto_increment, -- primary key and unique number assigned by Koha
2954 `budget_period_startdate` date NOT NULL, -- date when the budget starts
2955 `budget_period_enddate` date NOT NULL, -- date when the budget ends
2956 `budget_period_active` tinyint(1) default '0', -- whether this budget is active or not (1 for yes, 0 for no)
2957 `budget_period_description` mediumtext, -- description assigned to this budget
2958 `budget_period_total` decimal(28,6), -- total amount available in this budget
2959 `budget_period_locked` tinyint(1) default NULL, -- whether this budget is locked or not (1 for yes, 0 for no)
2960 `sort1_authcat` varchar(10) default NULL, -- statistical category for this budget
2961 `sort2_authcat` varchar(10) default NULL, -- second statistical category for this budget
2962 PRIMARY KEY (`budget_period_id`)
2963 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2966 -- Table structure for table `aqbudgets_planning`
2969 DROP TABLE IF EXISTS `aqbudgets_planning`;
2970 CREATE TABLE `aqbudgets_planning` (
2971 `plan_id` int(11) NOT NULL auto_increment,
2972 `budget_id` int(11) NOT NULL,
2973 `budget_period_id` int(11) NOT NULL,
2974 `estimated_amount` decimal(28,6) default NULL,
2975 `authcat` varchar(30) NOT NULL,
2976 `authvalue` varchar(30) NOT NULL,
2977 `display` tinyint(1) DEFAULT 1,
2978 PRIMARY KEY (`plan_id`),
2979 KEY `budget_period_id` (`budget_period_id`),
2980 CONSTRAINT `aqbudgets_planning_ifbk_1` FOREIGN KEY (`budget_id`) REFERENCES `aqbudgets` (`budget_id`) ON DELETE CASCADE ON UPDATE CASCADE
2981 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
2984 -- Table structure for table 'aqcontacts'
2987 DROP TABLE IF EXISTS aqcontacts;
2988 CREATE TABLE aqcontacts (
2989 id int(11) NOT NULL auto_increment, -- primary key and unique number assigned by Koha
2990 name varchar(100) default NULL, -- name of contact at vendor
2991 position varchar(100) default NULL, -- contact person's position
2992 phone varchar(100) default NULL, -- contact's phone number
2993 altphone varchar(100) default NULL, -- contact's alternate phone number
2994 fax varchar(100) default NULL, -- contact's fax number
2995 email varchar(100) default NULL, -- contact's email address
2996 notes mediumtext, -- notes related to the contact
2997 claimacquisition BOOLEAN NOT NULL DEFAULT 0, -- should this contact receive acquisitions claims
2998 claimissues BOOLEAN NOT NULL DEFAULT 0, -- should this contact receive serial claims
2999 acqprimary BOOLEAN NOT NULL DEFAULT 0, -- is this the primary contact for acquisitions messages
3000 serialsprimary BOOLEAN NOT NULL DEFAULT 0, -- is this the primary contact for serials messages
3001 booksellerid int(11) not NULL,
3003 CONSTRAINT booksellerid_aqcontacts_fk FOREIGN KEY (booksellerid)
3004 REFERENCES aqbooksellers (id) ON DELETE CASCADE ON UPDATE CASCADE
3005 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci AUTO_INCREMENT=1;
3008 -- Table structure for table 'aqcontract'
3011 DROP TABLE IF EXISTS `aqcontract`;
3012 CREATE TABLE `aqcontract` (
3013 `contractnumber` int(11) NOT NULL auto_increment,
3014 `contractstartdate` date default NULL,
3015 `contractenddate` date default NULL,
3016 `contractname` varchar(50) default NULL,
3017 `contractdescription` mediumtext,
3018 `booksellerid` int(11) not NULL,
3019 PRIMARY KEY (`contractnumber`),
3020 CONSTRAINT `booksellerid_fk1` FOREIGN KEY (`booksellerid`)
3021 REFERENCES `aqbooksellers` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
3022 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci AUTO_INCREMENT=1 ;
3025 -- Table structure for table `aqorders`
3028 DROP TABLE IF EXISTS `aqorders`;
3029 CREATE TABLE `aqorders` ( -- information related to the basket line items
3030 `ordernumber` int(11) NOT NULL auto_increment, -- primary key and unique identifier assigned by Koha to each line
3031 `biblionumber` int(11) default NULL, -- links the order to the biblio being ordered (biblio.biblionumber)
3032 `entrydate` date default NULL, -- the date the bib was added to the basket
3033 `quantity` smallint(6) default NULL, -- the quantity ordered
3034 `currency` varchar(3) default NULL, -- the currency used for the purchase
3035 `listprice` decimal(28,6) default NULL, -- the vendor price for this line item
3036 `datereceived` date default NULL, -- the date this order was received
3037 invoiceid int(11) default NULL, -- id of invoice
3038 `freight` decimal(28,6) default NULL, -- shipping costs (not used)
3039 `unitprice` decimal(28,6) default NULL, -- the actual cost entered when receiving this line item
3040 `quantityreceived` smallint(6) NOT NULL default 0, -- the quantity that have been received so far
3041 `datecancellationprinted` date default NULL, -- the date the line item was deleted
3042 `cancellationreason` text default NULL, -- reason of cancellation
3043 `order_internalnote` mediumtext, -- notes related to this order line, made for staff
3044 `order_vendornote` mediumtext, -- notes related to this order line, made for vendor
3045 `purchaseordernumber` mediumtext, -- not used? always NULL
3046 `basketno` int(11) default NULL, -- links this order line to a specific basket (aqbasket.basketno)
3047 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- the date and time this order line was last modified
3048 `rrp` decimal(13,2) default NULL, -- the replacement cost for this line item
3049 `ecost` decimal(13,2) default NULL, -- the estimated cost for this line item
3050 `gstrate` decimal(6,4) default NULL, -- the tax rate for this line item
3051 `discount` float(6,4) default NULL, -- the discount for this line item
3052 `budget_id` int(11) NOT NULL, -- the fund this order goes against (aqbudgets.budget_id)
3053 `budgetgroup_id` int(11) NOT NULL, -- not used? always zero
3054 `budgetdate` date default NULL, -- not used? always NULL
3055 `sort1` varchar(80) default NULL, -- statistical field
3056 `sort2` varchar(80) default NULL, -- second statistical field
3057 `sort1_authcat` varchar(10) default NULL,
3058 `sort2_authcat` varchar(10) default NULL,
3059 `uncertainprice` tinyint(1), -- was this price uncertain (1 for yes, 0 for no)
3060 `claims_count` int(11) default 0, -- count of claim letters generated
3061 `claimed_date` date default NULL, -- last date a claim was generated
3062 `subscriptionid` int(11) default NULL, -- links this order line to a subscription (subscription.subscriptionid)
3063 parent_ordernumber int(11) default NULL, -- ordernumber of parent order line, or same as ordernumber if no parent
3064 `orderstatus` varchar(16) default 'new', -- the current status for this line item. Can be 'new', 'ordered', 'partial', 'complete' or 'cancelled'
3065 PRIMARY KEY (`ordernumber`),
3066 KEY `basketno` (`basketno`),
3067 KEY `biblionumber` (`biblionumber`),
3068 KEY `budget_id` (`budget_id`),
3069 KEY `parent_ordernumber` (`parent_ordernumber`),
3070 KEY `orderstatus` (`orderstatus`),
3071 CONSTRAINT `aqorders_budget_id_fk` FOREIGN KEY (`budget_id`) REFERENCES `aqbudgets` (`budget_id`) ON DELETE CASCADE ON UPDATE CASCADE,
3072 CONSTRAINT `aqorders_ibfk_1` FOREIGN KEY (`basketno`) REFERENCES `aqbasket` (`basketno`) ON DELETE CASCADE ON UPDATE CASCADE,
3073 CONSTRAINT `aqorders_ibfk_2` FOREIGN KEY (`biblionumber`) REFERENCES `biblio` (`biblionumber`) ON DELETE SET NULL ON UPDATE CASCADE,
3074 CONSTRAINT aqorders_ibfk_3 FOREIGN KEY (invoiceid) REFERENCES aqinvoices (invoiceid) ON DELETE SET NULL ON UPDATE CASCADE,
3075 CONSTRAINT `aqorders_subscriptionid` FOREIGN KEY (`subscriptionid`) REFERENCES `subscription` (`subscriptionid`) ON DELETE CASCADE ON UPDATE CASCADE
3076 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3079 -- Table structure for table `aqorder_users`
3082 DROP TABLE IF EXISTS `aqorder_users`;
3083 CREATE TABLE aqorder_users ( -- Mapping orders to patrons for notification sending
3084 ordernumber int(11) NOT NULL, -- the order this patrons receive notifications from (aqorders.ordernumber)
3085 borrowernumber int(11) NOT NULL, -- the borrowernumber for the patron receiving notifications for this order (borrowers.borrowernumber)
3086 PRIMARY KEY (ordernumber, borrowernumber),
3087 CONSTRAINT aqorder_users_ibfk_1 FOREIGN KEY (ordernumber) REFERENCES aqorders (ordernumber) ON DELETE CASCADE ON UPDATE CASCADE,
3088 CONSTRAINT aqorder_users_ibfk_2 FOREIGN KEY (borrowernumber) REFERENCES borrowers (borrowernumber) ON DELETE CASCADE ON UPDATE CASCADE
3089 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3092 -- Table structure for table `aqorders_items`
3095 DROP TABLE IF EXISTS `aqorders_items`;
3096 CREATE TABLE `aqorders_items` ( -- information on items entered in the acquisitions process
3097 `ordernumber` int(11) NOT NULL, -- the order this item is attached to (aqorders.ordernumber)
3098 `itemnumber` int(11) NOT NULL, -- the item number for this item (items.itemnumber)
3099 `timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, -- the date and time this order item was last touched
3100 PRIMARY KEY (`itemnumber`),
3101 KEY `ordernumber` (`ordernumber`),
3102 CONSTRAINT aqorders_items_ibfk_1 FOREIGN KEY (ordernumber) REFERENCES aqorders (ordernumber) ON DELETE CASCADE ON UPDATE CASCADE
3103 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3107 -- Table structure for table aqorders_transfers
3110 DROP TABLE IF EXISTS aqorders_transfers;
3111 CREATE TABLE aqorders_transfers (
3112 ordernumber_from int(11) NULL,
3113 ordernumber_to int(11) NULL,
3114 timestamp timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
3115 UNIQUE KEY ordernumber_from (ordernumber_from),
3116 UNIQUE KEY ordernumber_to (ordernumber_to),
3117 CONSTRAINT aqorders_transfers_ordernumber_from FOREIGN KEY (ordernumber_from) REFERENCES aqorders (ordernumber) ON DELETE SET NULL ON UPDATE CASCADE,
3118 CONSTRAINT aqorders_transfers_ordernumber_to FOREIGN KEY (ordernumber_to) REFERENCES aqorders (ordernumber) ON DELETE SET NULL ON UPDATE CASCADE
3119 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3122 -- Table structure for table aqinvoices
3125 DROP TABLE IF EXISTS aqinvoices;
3126 CREATE TABLE aqinvoices (
3127 invoiceid int(11) NOT NULL AUTO_INCREMENT, -- ID of the invoice, primary key
3128 invoicenumber mediumtext NOT NULL, -- Name of invoice
3129 booksellerid int(11) NOT NULL, -- foreign key to aqbooksellers
3130 shipmentdate date default NULL, -- date of shipment
3131 billingdate date default NULL, -- date of billing
3132 closedate date default NULL, -- invoice close date, NULL means the invoice is open
3133 shipmentcost decimal(28,6) default NULL, -- shipment cost
3134 shipmentcost_budgetid int(11) default NULL, -- foreign key to aqbudgets, link the shipment cost to a budget
3135 PRIMARY KEY (invoiceid),
3136 CONSTRAINT aqinvoices_fk_aqbooksellerid FOREIGN KEY (booksellerid) REFERENCES aqbooksellers (id) ON DELETE CASCADE ON UPDATE CASCADE,
3137 CONSTRAINT aqinvoices_fk_shipmentcost_budgetid FOREIGN KEY (shipmentcost_budgetid) REFERENCES aqbudgets (budget_id) ON DELETE SET NULL ON UPDATE CASCADE
3138 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3142 -- Table structure for table `fieldmapping`
3145 DROP TABLE IF EXISTS `fieldmapping`;
3146 CREATE TABLE `fieldmapping` ( -- koha to keyword mapping
3147 `id` int(11) NOT NULL auto_increment, -- unique identifier assigned by Koha
3148 `field` varchar(255) NOT NULL, -- keyword to be mapped to (ex. subtitle)
3149 `frameworkcode` char(4) NOT NULL default '', -- foreign key from the biblio_framework table to link this mapping to a specific framework
3150 `fieldcode` char(3) NOT NULL, -- marc field number to map to this keyword
3151 `subfieldcode` char(1) NOT NULL, -- marc subfield associated with the fieldcode to map to this keyword
3153 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3156 -- Table structure for table `transport_cost`
3159 DROP TABLE IF EXISTS transport_cost;
3160 CREATE TABLE transport_cost (
3161 frombranch varchar(10) NOT NULL,
3162 tobranch varchar(10) NOT NULL,
3163 cost decimal(6,2) NOT NULL,
3164 disable_transfer tinyint(1) NOT NULL DEFAULT 0,
3165 CHECK ( frombranch <> tobranch ), -- a dud check, mysql does not support that
3166 PRIMARY KEY (frombranch, tobranch),
3167 CONSTRAINT transport_cost_ibfk_1 FOREIGN KEY (frombranch) REFERENCES branches (branchcode) ON DELETE CASCADE ON UPDATE CASCADE,
3168 CONSTRAINT transport_cost_ibfk_2 FOREIGN KEY (tobranch) REFERENCES branches (`branchcode`) ON DELETE CASCADE ON UPDATE CASCADE
3169 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3172 -- Table structure for table `biblioimages`
3175 DROP TABLE IF EXISTS `biblioimages`;
3177 CREATE TABLE `biblioimages` ( -- local cover images
3178 `imagenumber` int(11) NOT NULL AUTO_INCREMENT, -- unique identifier for the image
3179 `biblionumber` int(11) NOT NULL, -- foreign key from biblio table to link to biblionumber
3180 `mimetype` varchar(15) NOT NULL, -- image type
3181 `imagefile` mediumblob NOT NULL, -- image file contents
3182 `thumbnail` mediumblob NOT NULL, -- thumbnail file contents
3183 PRIMARY KEY (`imagenumber`),
3184 CONSTRAINT `bibliocoverimage_fk1` FOREIGN KEY (`biblionumber`) REFERENCES `biblio` (`biblionumber`) ON DELETE CASCADE ON UPDATE CASCADE
3185 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3188 -- Table structure for table `social_data`
3191 DROP TABLE IF EXISTS `social_data`;
3192 CREATE TABLE IF NOT EXISTS `social_data` (
3195 `num_critics_pro` INT,
3196 `num_quotations` INT,
3198 `score_avg` DECIMAL(5,2),
3200 PRIMARY KEY (`isbn`)
3201 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3204 -- 'Ratings' table. This tracks the star ratings set by borrowers.
3207 DROP TABLE IF EXISTS ratings;
3208 CREATE TABLE ratings ( -- information related to the star ratings in the OPAC
3209 borrowernumber int(11) NOT NULL, -- the borrowernumber of the patron who left this rating (borrowers.borrowernumber)
3210 biblionumber int(11) NOT NULL, -- the biblio this rating is for (biblio.biblionumber)
3211 rating_value tinyint(1) NOT NULL, -- the rating, from 1 to 5
3212 timestamp timestamp NOT NULL default CURRENT_TIMESTAMP,
3213 PRIMARY KEY (borrowernumber,biblionumber),
3214 CONSTRAINT ratings_ibfk_1 FOREIGN KEY (borrowernumber) REFERENCES borrowers (borrowernumber) ON DELETE CASCADE ON UPDATE CASCADE,
3215 CONSTRAINT ratings_ibfk_2 FOREIGN KEY (biblionumber) REFERENCES biblio (biblionumber) ON DELETE CASCADE ON UPDATE CASCADE
3216 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3219 -- Table structure for table `quotes`
3222 DROP TABLE IF EXISTS quotes;
3223 CREATE TABLE `quotes` ( -- data for the quote of the day feature
3224 `id` int(11) NOT NULL AUTO_INCREMENT, -- unique id for the quote
3225 `source` text DEFAULT NULL, -- source/credit for the quote
3226 `text` mediumtext NOT NULL, -- text of the quote
3227 `timestamp` datetime NOT NULL, -- date and time that the quote last appeared in the opac
3229 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3232 -- Table structure for table categories_branches
3235 DROP TABLE IF EXISTS categories_branches;
3236 CREATE TABLE categories_branches( -- association table between categories and branches
3237 categorycode VARCHAR(10),
3238 branchcode VARCHAR(10),
3239 FOREIGN KEY (categorycode) REFERENCES categories(categorycode) ON DELETE CASCADE,
3240 FOREIGN KEY (branchcode) REFERENCES branches(branchcode) ON DELETE CASCADE
3241 ) ENGINE=INNODB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3244 -- Table structure for table authorised_values_branches
3247 DROP TABLE IF EXISTS authorised_values_branches;
3248 CREATE TABLE authorised_values_branches( -- association table between authorised_values and branches
3249 av_id INT(11) NOT NULL,
3250 branchcode VARCHAR(10) NOT NULL,
3251 FOREIGN KEY (av_id) REFERENCES authorised_values(id) ON DELETE CASCADE,
3252 FOREIGN KEY (branchcode) REFERENCES branches(branchcode) ON DELETE CASCADE
3253 ) ENGINE=INNODB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3257 -- Table structure for table borrower_attribute_types_branches
3260 DROP TABLE IF EXISTS borrower_attribute_types_branches;
3261 CREATE TABLE borrower_attribute_types_branches( -- association table between borrower_attribute_types and branches
3262 bat_code VARCHAR(10),
3263 b_branchcode VARCHAR(10),
3264 FOREIGN KEY (bat_code) REFERENCES borrower_attribute_types(code) ON DELETE CASCADE,
3265 FOREIGN KEY (b_branchcode) REFERENCES branches(branchcode) ON DELETE CASCADE
3266 ) ENGINE=INNODB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3269 -- Table structure for table `borrower_modifications`
3272 CREATE TABLE IF NOT EXISTS `borrower_modifications` (
3273 `timestamp` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
3274 `verification_token` varchar(255) NOT NULL DEFAULT '',
3275 `borrowernumber` int(11) NOT NULL DEFAULT '0',
3276 `cardnumber` varchar(16) DEFAULT NULL,
3277 `surname` mediumtext,
3280 `othernames` mediumtext,
3282 `streetnumber` varchar(10) DEFAULT NULL,
3283 `streettype` varchar(50) DEFAULT NULL,
3284 `address` mediumtext,
3288 `zipcode` varchar(25) DEFAULT NULL,
3292 `mobile` varchar(50) DEFAULT NULL,
3296 `B_streetnumber` varchar(10) DEFAULT NULL,
3297 `B_streettype` varchar(50) DEFAULT NULL,
3298 `B_address` varchar(100) DEFAULT NULL,
3300 `B_city` mediumtext,
3302 `B_zipcode` varchar(25) DEFAULT NULL,
3305 `B_phone` mediumtext,
3306 `dateofbirth` date DEFAULT NULL,
3307 `branchcode` varchar(10) DEFAULT NULL,
3308 `categorycode` varchar(10) DEFAULT NULL,
3309 `dateenrolled` date DEFAULT NULL,
3310 `dateexpiry` date DEFAULT NULL,
3311 `gonenoaddress` tinyint(1) DEFAULT NULL,
3312 `lost` tinyint(1) DEFAULT NULL,
3313 `debarred` date DEFAULT NULL,
3314 `debarredcomment` varchar(255) DEFAULT NULL,
3315 `contactname` mediumtext,
3316 `contactfirstname` text,
3317 `contacttitle` text,
3318 `guarantorid` int(11) DEFAULT NULL,
3319 `borrowernotes` mediumtext,
3320 `relationship` varchar(100) DEFAULT NULL,
3321 `sex` varchar(1) DEFAULT NULL,
3322 `password` varchar(30) DEFAULT NULL,
3323 `flags` int(11) DEFAULT NULL,
3324 `userid` varchar(75) DEFAULT NULL,
3325 `opacnote` mediumtext,
3326 `contactnote` varchar(255) DEFAULT NULL,
3327 `sort1` varchar(80) DEFAULT NULL,
3328 `sort2` varchar(80) DEFAULT NULL,
3329 `altcontactfirstname` varchar(255) DEFAULT NULL,
3330 `altcontactsurname` varchar(255) DEFAULT NULL,
3331 `altcontactaddress1` varchar(255) DEFAULT NULL,
3332 `altcontactaddress2` varchar(255) DEFAULT NULL,
3333 `altcontactaddress3` varchar(255) DEFAULT NULL,
3334 `altcontactstate` text,
3335 `altcontactzipcode` varchar(50) DEFAULT NULL,
3336 `altcontactcountry` text,
3337 `altcontactphone` varchar(50) DEFAULT NULL,
3338 `smsalertnumber` varchar(50) DEFAULT NULL,
3339 `privacy` int(11) DEFAULT NULL,
3340 PRIMARY KEY (`verification_token`,`borrowernumber`),
3341 KEY `verification_token` (`verification_token`),
3342 KEY `borrowernumber` (`borrowernumber`)
3343 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3346 -- Table structure for table uploaded_files
3349 DROP TABLE IF EXISTS uploaded_files;
3350 CREATE TABLE uploaded_files (
3351 id int(11) NOT NULL AUTO_INCREMENT,
3352 hashvalue CHAR(40) NOT NULL,
3353 filename TEXT NOT NULL,
3356 dtcreated timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
3357 uploadcategorycode tinytext,
3362 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3365 -- Table structure for table linktracker
3366 -- This stores clicks to external links
3369 DROP TABLE IF EXISTS linktracker;
3370 CREATE TABLE linktracker (
3371 id int(11) NOT NULL AUTO_INCREMENT, -- primary key identifier
3372 biblionumber int(11) DEFAULT NULL, -- biblionumber of the record the link is from
3373 itemnumber int(11) DEFAULT NULL, -- itemnumber if applicable that the link was from
3374 borrowernumber int(11) DEFAULT NULL, -- borrowernumber who clicked the link
3375 url text, -- the link itself
3376 timeclicked datetime DEFAULT NULL, -- the date and time the link was clicked
3378 KEY bibidx (biblionumber),
3379 KEY itemidx (itemnumber),
3380 KEY borridx (borrowernumber),
3381 KEY dateidx (timeclicked)
3382 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3385 -- Table structure for table 'plugin_data'
3388 CREATE TABLE IF NOT EXISTS plugin_data (
3389 plugin_class varchar(255) NOT NULL,
3390 plugin_key varchar(255) NOT NULL,
3392 PRIMARY KEY (plugin_class,plugin_key)
3393 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3396 -- Table structure for table `patron_lists`
3399 DROP TABLE IF EXISTS patron_lists;
3400 CREATE TABLE patron_lists (
3401 patron_list_id int(11) NOT NULL AUTO_INCREMENT, -- unique identifier
3402 name varchar(255) CHARACTER SET utf8 NOT NULL, -- the list's name
3403 owner int(11) NOT NULL, -- borrowernumber of the list creator
3404 PRIMARY KEY (patron_list_id),
3406 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3409 -- Constraints for table `patron_lists`
3411 ALTER TABLE `patron_lists`
3412 ADD CONSTRAINT patron_lists_ibfk_1 FOREIGN KEY (`owner`) REFERENCES borrowers (borrowernumber) ON DELETE CASCADE ON UPDATE CASCADE;
3415 -- Table structure for table 'patron_list_patrons'
3418 DROP TABLE IF EXISTS patron_list_patrons;
3419 CREATE TABLE patron_list_patrons (
3420 patron_list_patron_id int(11) NOT NULL AUTO_INCREMENT, -- unique identifier
3421 patron_list_id int(11) NOT NULL, -- the list this entry is part of
3422 borrowernumber int(11) NOT NULL, -- the borrower that is part of this list
3423 PRIMARY KEY (patron_list_patron_id),
3424 KEY patron_list_id (patron_list_id),
3425 KEY borrowernumber (borrowernumber)
3426 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3429 -- Constraints for table `patron_list_patrons`
3431 ALTER TABLE `patron_list_patrons`
3432 ADD CONSTRAINT patron_list_patrons_ibfk_1 FOREIGN KEY (patron_list_id) REFERENCES patron_lists (patron_list_id) ON DELETE CASCADE ON UPDATE CASCADE,
3433 ADD CONSTRAINT patron_list_patrons_ibfk_2 FOREIGN KEY (borrowernumber) REFERENCES borrowers (borrowernumber) ON DELETE CASCADE ON UPDATE CASCADE;
3436 -- Table structure for table 'marc_modification_templates'
3439 CREATE TABLE IF NOT EXISTS marc_modification_templates (
3440 template_id int(11) NOT NULL AUTO_INCREMENT,
3442 PRIMARY KEY (template_id)
3443 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3446 -- Table structure for table 'marc_modification_template_actions'
3449 CREATE TABLE IF NOT EXISTS marc_modification_template_actions (
3450 mmta_id int(11) NOT NULL AUTO_INCREMENT,
3451 template_id int(11) NOT NULL,
3452 ordering int(3) NOT NULL,
3453 action enum('delete_field','update_field','move_field','copy_field') NOT NULL,
3454 field_number smallint(6) NOT NULL DEFAULT '0',
3455 from_field varchar(3) NOT NULL,
3456 from_subfield varchar(1) DEFAULT NULL,
3457 field_value varchar(100) DEFAULT NULL,
3458 to_field varchar(3) DEFAULT NULL,
3459 to_subfield varchar(1) DEFAULT NULL,
3460 to_regex_search text,
3461 to_regex_replace text,
3462 to_regex_modifiers varchar(8) DEFAULT '',
3463 conditional enum('if','unless') DEFAULT NULL,
3464 conditional_field varchar(3) DEFAULT NULL,
3465 conditional_subfield varchar(1) DEFAULT NULL,
3466 conditional_comparison enum('exists','not_exists','equals','not_equals') DEFAULT NULL,
3467 conditional_value text,
3468 conditional_regex tinyint(1) NOT NULL DEFAULT '0',
3470 PRIMARY KEY (mmta_id),
3471 CONSTRAINT `mmta_ibfk_1` FOREIGN KEY (`template_id`) REFERENCES `marc_modification_templates` (`template_id`) ON DELETE CASCADE ON UPDATE CASCADE
3472 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3475 -- Table structure for table `misc_files`
3478 CREATE TABLE IF NOT EXISTS `misc_files` ( -- miscellaneous files attached to records from various tables
3479 `file_id` int(11) NOT NULL AUTO_INCREMENT, -- unique id for the file record
3480 `table_tag` varchar(255) NOT NULL, -- usually table name, or arbitrary unique tag
3481 `record_id` int(11) NOT NULL, -- record id from the table this file is associated to
3482 `file_name` varchar(255) NOT NULL, -- file name
3483 `file_type` varchar(255) NOT NULL, -- MIME type of the file
3484 `file_description` varchar(255) DEFAULT NULL, -- description given to the file
3485 `file_content` longblob NOT NULL, -- file content
3486 `date_uploaded` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, -- date and time the file was added
3487 PRIMARY KEY (`file_id`),
3488 KEY `table_tag` (`table_tag`),
3489 KEY `record_id` (`record_id`)
3490 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3493 -- Table structure for table `columns_settings`
3496 CREATE TABLE IF NOT EXISTS columns_settings (
3497 module varchar(255) NOT NULL,
3498 page varchar(255) NOT NULL,
3499 tablename varchar(255) NOT NULL,
3500 columnname varchar(255) NOT NULL,
3501 cannot_be_toggled int(1) NOT NULL DEFAULT 0,
3502 is_hidden int(1) NOT NULL DEFAULT 0,
3503 PRIMARY KEY(module, page, tablename, columnname)
3504 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3507 -- Table structure for table 'items_search_fields'
3510 DROP TABLE IF EXISTS items_search_fields;
3511 CREATE TABLE items_search_fields (
3512 name VARCHAR(255) NOT NULL,
3513 label VARCHAR(255) NOT NULL,
3514 tagfield CHAR(3) NOT NULL,
3515 tagsubfield CHAR(1) NULL DEFAULT NULL,
3516 authorised_values_category VARCHAR(32) NULL DEFAULT NULL,
3518 CONSTRAINT items_search_fields_authorised_values_category
3519 FOREIGN KEY (authorised_values_category) REFERENCES authorised_values (category)
3520 ON DELETE SET NULL ON UPDATE CASCADE
3521 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3524 -- Table structure for table 'discharges'
3527 DROP TABLE IF EXISTS discharges;
3528 CREATE TABLE discharges (
3529 discharge_id int(11) NOT NULL AUTO_INCREMENT,
3530 borrower int(11) DEFAULT NULL,
3531 needed timestamp NULL DEFAULT NULL,
3532 validated timestamp NULL DEFAULT NULL,
3533 PRIMARY KEY (discharge_id),
3534 KEY borrower_discharges_ibfk1 (borrower),
3535 CONSTRAINT borrower_discharges_ibfk1 FOREIGN KEY (borrower) REFERENCES borrowers (borrowernumber) ON DELETE CASCADE ON UPDATE CASCADE
3536 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3539 -- Table structure for table additional_fields
3540 -- This table add the ability to add new fields for a record
3543 CREATE TABLE `additional_fields` (
3544 `id` int(11) NOT NULL AUTO_INCREMENT, -- primary key identifier
3545 `tablename` varchar(255) NOT NULL DEFAULT '', -- tablename of the new field
3546 `name` varchar(255) NOT NULL DEFAULT '', -- name of the field
3547 `authorised_value_category` varchar(16) NOT NULL DEFAULT '', -- is an authorised value category
3548 `marcfield` varchar(16) NOT NULL DEFAULT '', -- contains the marc field to copied into the record
3549 `searchable` tinyint(1) NOT NULL DEFAULT '0', -- is the field searchable?
3551 UNIQUE KEY `fields_uniq` (`tablename`,`name`)
3552 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3555 -- Table structure for table additional_field_values
3556 -- This table store values for additional fields
3559 CREATE TABLE `additional_field_values` (
3560 `id` int(11) NOT NULL AUTO_INCREMENT, -- primary key identifier
3561 `field_id` int(11) NOT NULL, -- foreign key references additional_fields(id)
3562 `record_id` int(11) NOT NULL, -- record_id
3563 `value` varchar(255) NOT NULL DEFAULT '', -- value for this field
3565 UNIQUE KEY `field_record` (`field_id`,`record_id`),
3566 CONSTRAINT `afv_fk` FOREIGN KEY (`field_id`) REFERENCES `additional_fields` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
3567 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3570 -- Table structure for table 'localization'
3573 DROP TABLE IF EXISTS localization;
3574 CREATE TABLE `localization` (
3575 localization_id int(11) NOT NULL AUTO_INCREMENT,
3576 entity varchar(16) COLLATE utf8_unicode_ci NOT NULL,
3577 code varchar(64) COLLATE utf8_unicode_ci NOT NULL,
3578 lang varchar(25) COLLATE utf8_unicode_ci NOT NULL, -- could be a foreign key
3579 translation text COLLATE utf8_unicode_ci,
3580 PRIMARY KEY (localization_id),
3581 UNIQUE KEY `entity_code_lang` (`entity`,`code`,`lang`)
3582 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3585 -- Table structure for table 'audio_alerts'
3588 DROP TABLE IF EXISTS audio_alerts;
3589 CREATE TABLE audio_alerts (
3590 audio_alert_id int(11) NOT NULL AUTO_INCREMENT,
3591 precedence smallint(5) unsigned NOT NULL,
3592 selector varchar(255) NOT NULL,
3593 sound varchar(255) NOT NULL,
3594 PRIMARY KEY (audio_alert_id),
3595 KEY precedence (precedence)
3596 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
3598 /*!40103 SET TIME_ZONE=@OLD_TIME_ZONE */;
3599 /*!40101 SET SQL_MODE=@OLD_SQL_MODE */;
3600 /*!40014 SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS */;
3601 /*!40014 SET UNIQUE_CHECKS=@OLD_UNIQUE_CHECKS */;
3602 /*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */;
3603 /*!40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */;
3604 /*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */;
3605 /*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */;