--- /dev/null
+--
+-- Copyright Samalyse SARL, 2008
+-- Auteur: Olivier Guilyardi <olivier@samalyse.com>
+--
+-- Structure de la nouvelle base du CREM
+--
+-- Ce logiciel est régi par la licence CeCILL soumise au droit français et
+-- respectant les principes de diffusion des logiciels libres. Vous pouvez
+-- utiliser, modifier et/ou redistribuer ce programme sous les conditions
+-- de la licence CeCILL telle que diffusée par le CEA, le CNRS et l'INRIA
+-- sur le site "http://www.cecill.info".
+--
+-- En contrepartie de l'accessibilité au code source et des droits de copie,
+-- de modification et de redistribution accordés par cette licence, il n'est
+-- offert aux utilisateurs qu'une garantie limitée. Pour les mêmes raisons,
+-- seule une responsabilité restreinte pèse sur l'auteur du programme, le
+-- titulaire des droits patrimoniaux et les concédants successifs.
+--
+-- A cet égard l'attention de l'utilisateur est attirée sur les risques
+-- associés au chargement, à l'utilisation, à la modification et/ou au
+-- développement et à la reproduction du logiciel par l'utilisateur étant
+-- donné sa spécificité de logiciel libre, qui peut le rendre complexe à
+-- manipuler et qui le réserve donc à des développeurs et des professionnels
+-- avertis possédant des connaissances informatiques approfondies. Les
+-- utilisateurs sont donc invités à charger et tester l'adéquation du
+-- logiciel à leurs besoins dans des conditions permettant d'assurer la
+-- sécurité de leurs systèmes et ou de leurs données et, plus généralement,
+-- à l'utiliser et l'exploiter dans les mêmes conditions de sécurité.
+--
+-- Le fait que vous puissiez accéder à cet en-tête signifie que vous avez
+-- pris connaissance de la licence CeCILL, et que vous en avez accepté les
+-- termes.
+--
+-- SVN:$Id$
+--
+
+-- Règles générales concernant la valeur nulle et les valeurs par défaut:
+--
+-- - si un champ, clé étrangère ou non, ne doit pas être vide, il est définit
+-- non nul et sans valeur par défaut
+-- - si un champ qui n'est pas une clé étrangère peut être vide, il est définit
+-- comme ne pouvant être nul et avec une valeur vide par défaut
+-- - si un champ qui est une clé étrangère peut être vide, il est définit comme
+-- pouvant être nul et sans valeur par défaut
+
+--
+-- Enumérations simples
+--
+
+CREATE TABLE physical_formats (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ value VARCHAR(250) NOT NULL UNIQUE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE publishing_status (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ value VARCHAR(250) NOT NULL UNIQUE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE acquisition_modes (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ value VARCHAR(250) NOT NULL UNIQUE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE metadata_authors (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ value VARCHAR(250) NOT NULL UNIQUE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE metadata_writers (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ value VARCHAR(250) NOT NULL UNIQUE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE legal_rights (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ value VARCHAR(250) NOT NULL UNIQUE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE recording_contexts (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ value VARCHAR(250) NOT NULL UNIQUE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE ad_conversions (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ value VARCHAR(250) NOT NULL UNIQUE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE vernacular_styles (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ value VARCHAR(250) NOT NULL UNIQUE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE generic_styles (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ value VARCHAR(250) NOT NULL UNIQUE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+--
+-- Editeurs et collections
+--
+
+CREATE TABLE publishers (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ value VARCHAR(250) NOT NULL UNIQUE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE publisher_collections (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ publisher_id INTEGER NOT NULL,
+ value VARCHAR(250) NOT NULL,
+
+ FOREIGN KEY(publisher_id) REFERENCES publishers (id) ON DELETE CASCADE,
+ UNIQUE (publisher_id, value)
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+--
+-- Thésaurus géographique
+--
+
+CREATE TABLE location_types (
+ id VARCHAR(64) NOT NULL PRIMARY KEY,
+ name VARCHAR(150) NOT NULL
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE locations (
+ name VARCHAR(150) NOT NULL PRIMARY KEY,
+ type ENUM('country', 'continent', 'other') NOT NULL,
+ complete_type_id VARCHAR(64) NOT NULL,
+ current_name VARCHAR(150), -- recursif
+ is_authoritative BOOLEAN NOT NULL DEFAULT 0,
+
+ FOREIGN KEY(current_name) REFERENCES locations (name) ON DELETE SET NULL ON UPDATE CASCADE,
+ FOREIGN KEY(complete_type_id) REFERENCES location_types (id) ON DELETE CASCADE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE location_aliases (
+ location_name VARCHAR(150) NOT NULL,
+ alias VARCHAR(150) NOT NULL,
+ is_authoritative BOOLEAN NOT NULL DEFAULT 0,
+
+ PRIMARY KEY(location_name, alias),
+ FOREIGN KEY(location_name) REFERENCES locations (name)
+ ON DELETE CASCADE ON UPDATE CASCADE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE location_relations (
+ location_name VARCHAR(150) NOT NULL,
+ parent_location_name VARCHAR(150),
+
+ PRIMARY KEY(location_name, parent_location_name),
+ FOREIGN KEY(location_name) REFERENCES locations (name)
+ ON DELETE CASCADE ON UPDATE CASCADE,
+ FOREIGN KEY(parent_location_name) REFERENCES locations (name)
+ ON DELETE CASCADE ON UPDATE CASCADE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+--
+-- Ethnies
+--
+
+CREATE TABLE ethnic_groups (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ name VARCHAR(250) NOT NULL
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE ethnic_group_aliases (
+ ethnic_group_id INTEGER NOT NULL,
+ name VARCHAR(250) NOT NULL,
+
+ FOREIGN KEY(ethnic_group_id) REFERENCES ethnic_groups (id) ON DELETE CASCADE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+--
+-- Collections
+--
+
+CREATE TABLE media_collections (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ reference VARCHAR(250) UNIQUE,
+ physical_format_id INTEGER,
+ old_code VARCHAR(250) NOT NULL UNIQUE,
+ code VARCHAR(250) NOT NULL UNIQUE,
+ title VARCHAR(250) NOT NULL,
+ alt_title VARCHAR(250) NOT NULL DEFAULT '',
+ physical_items_num INTEGER NOT NULL DEFAULT 0,
+ publishing_status_id INTEGER,
+ creator VARCHAR(250) NOT NULL DEFAULT '',
+ booklet_author VARCHAR(250) NOT NULL DEFAULT '',
+ booklet_description TEXT NOT NULL DEFAULT '',
+ collector VARCHAR(250) NOT NULL DEFAULT '',
+ collector_is_creator BOOLEAN NOT NULL DEFAULT 0,
+ publisher_id INTEGER,
+ year_published INTEGER NOT NULL DEFAULT 0,
+ publisher_collection_id INTEGER,
+ publisher_serial VARCHAR(250) NOT NULL DEFAULT '',
+ external_references TEXT NOT NULL DEFAULT '',
+ acquisition_mode_id INTEGER,
+ comment TEXT NOT NULL DEFAULT '',
+ metadata_author_id INTEGER,
+ metadata_writer_id INTEGER,
+ legal_rights_id INTEGER,
+ alt_ids VARCHAR(250) NOT NULL DEFAULT '',
+ recorded_from_year INTEGER NOT NULL DEFAULT 0,
+ recorded_to_year INTEGER NOT NULL DEFAULT 0,
+ recording_context_id INTEGER,
+ approx_duration TIME NOT NULL DEFAULT 0,
+ doctype_code INTEGER NOT NULL DEFAULT 0,
+ travail VARCHAR(250) NOT NULL DEFAULT '',
+ state TEXT NOT NULL DEFAULT '',
+ cnrs_contributor VARCHAR(250) NOT NULL DEFAULT '',
+ items_done VARCHAR(250) NOT NULL DEFAULT '',
+ a_informer_07_03 VARCHAR(250) NOT NULL DEFAULT '',
+ ad_conversion_id INTEGER,
+ public_access ENUM('none', 'metadata', 'full') NOT NULL DEFAULT 'metadata',
+
+ FOREIGN KEY(ad_conversion_id) REFERENCES ad_conversions (id)
+ ON DELETE SET NULL,
+ FOREIGN KEY(publisher_collection_id) REFERENCES publisher_collections (id)
+ ON DELETE SET NULL,
+ FOREIGN KEY(recording_context_id) REFERENCES recording_contexts (id)
+ ON DELETE SET NULL,
+ FOREIGN KEY(publisher_id) REFERENCES publishers (id)
+ ON DELETE SET NULL,
+ FOREIGN KEY(metadata_author_id) REFERENCES metadata_authors (id)
+ ON DELETE SET NULL,
+ FOREIGN KEY(physical_format_id) REFERENCES physical_formats (id)
+ ON DELETE SET NULL,
+ FOREIGN KEY(metadata_writer_id) REFERENCES metadata_writers (id)
+ ON DELETE SET NULL,
+ FOREIGN KEY(legal_rights_id) REFERENCES legal_rights (id)
+ ON DELETE SET NULL,
+ FOREIGN KEY(acquisition_mode_id) REFERENCES acquisition_modes (id)
+ ON DELETE SET NULL,
+ FOREIGN KEY(publishing_status_id) REFERENCES publishing_status (id)
+ ON DELETE SET NULL
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+--
+-- Items
+--
+
+CREATE TABLE media_items (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ collection_id INTEGER NOT NULL,
+ track VARCHAR(250) NOT NULL DEFAULT '',
+ old_code VARCHAR(250) UNIQUE NOT NULL,
+ code VARCHAR(250) UNIQUE, -- Doit être unique mais peut être inconnu
+ approx_duration TIME NOT NULL DEFAULT 0,
+ recorded_from_date DATE NOT NULL DEFAULT 0,
+ recorded_to_date DATE NOT NULL DEFAULT 0,
+ location_name VARCHAR(250),
+ location_comment VARCHAR(250) NOT NULL DEFAULT '',
+ ethnic_group_id INTEGER,
+ title VARCHAR(250) NOT NULL,
+ alt_title VARCHAR(250) NOT NULL DEFAULT '',
+ author VARCHAR(250) NOT NULL DEFAULT '',
+ vernacular_style_id INTEGER,
+ context_comment TEXT NOT NULL DEFAULT '',
+ external_references TEXT NOT NULL DEFAULT '',
+ moda_execut VARCHAR(250) NOT NULL DEFAULT '',
+ copied_from_item_id INTEGER, -- recursif
+ collector VARCHAR(250) NOT NULL DEFAULT '',
+ cultural_area VARCHAR(250) NOT NULL DEFAULT '',
+ generic_style_id INTEGER,
+ collector_selection VARCHAR(250) NOT NULL DEFAULT '',
+ creator_reference VARCHAR(250) NOT NULL DEFAULT '',
+ comment TEXT NOT NULL DEFAULT '',
+ filename VARCHAR(250) NOT NULL DEFAULT '',
+ public_access ENUM('none', 'metadata', 'full') NOT NULL DEFAULT 'metadata',
+
+ FOREIGN KEY(collection_id) REFERENCES media_collections (id)
+ ON DELETE CASCADE,
+ FOREIGN KEY(location_name) REFERENCES locations (name)
+ ON DELETE SET NULL,
+ FOREIGN KEY(ethnic_group_id) REFERENCES ethnic_groups (id)
+ ON DELETE SET NULL,
+ FOREIGN KEY(vernacular_style_id) REFERENCES vernacular_styles (id)
+ ON DELETE SET NULL,
+ FOREIGN KEY(location_name) REFERENCES locations (name)
+ ON DELETE SET NULL,
+ FOREIGN KEY(copied_from_item_id) REFERENCES media_items (id)
+ ON DELETE SET NULL,
+ FOREIGN KEY(generic_style_id) REFERENCES generic_styles (id)
+ ON DELETE SET NULL
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+--
+-- Parties d'item/marqueurs
+--
+
+CREATE TABLE media_parts (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ item_id INTEGER NOT NULL,
+ title VARCHAR(250) NOT NULL,
+ start FLOAT NOT NULL,
+ end FLOAT NOT NULL,
+
+ FOREIGN KEY(item_id) REFERENCES media_items (id) ON DELETE CASCADE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+--
+-- Instruments et formations
+--
+
+CREATE TABLE instruments (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ name VARCHAR(250) NOT NULL
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE instrument_relations (
+ instrument_id INTEGER NOT NULL,
+ parent_instrument_id INTEGER NOT NULL,
+
+ PRIMARY KEY(instrument_id, parent_instrument_id),
+ FOREIGN KEY(instrument_id) REFERENCES instruments (id)
+ ON DELETE CASCADE,
+ FOREIGN KEY(parent_instrument_id) REFERENCES instruments (id)
+ ON DELETE CASCADE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE instrument_aliases (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ name VARCHAR(250) NOT NULL
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE instrument_alias_relations (
+ alias_id INTEGER NOT NULL,
+ instrument_id INTEGER NOT NULL,
+
+ PRIMARY KEY(alias_id, instrument_id),
+ FOREIGN KEY(alias_id) REFERENCES instrument_aliases (id)
+ ON DELETE CASCADE,
+ FOREIGN KEY(instrument_id) REFERENCES instruments (id)
+ ON DELETE CASCADE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE media_item_performances (
+ media_item_id INTEGER NOT NULL,
+ instrument_id INTEGER,
+ alias_id INTEGER,
+ instruments_num VARCHAR(250) NOT NULL DEFAULT '',
+ musicians VARCHAR(250) NOT NULL DEFAULT '',
+
+ FOREIGN KEY(media_item_id) REFERENCES media_items (id)
+ ON DELETE CASCADE,
+ FOREIGN KEY(instrument_id) REFERENCES instruments (id)
+ ON DELETE SET NULL,
+ FOREIGN KEY(alias_id) REFERENCES instrument_aliases (id)
+ ON DELETE SET NULL
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+--
+-- Contexte ethnographique
+--
+
+CREATE TABLE context_keywords (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ value VARCHAR(250) NOT NULL
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE media_item_keywords (
+ item_id INTEGER NOT NULL,
+ keyword_id INTEGER NOT NULL,
+
+ PRIMARY KEY(item_id, keyword_id),
+ FOREIGN KEY(item_id) REFERENCES media_items (id) ON DELETE CASCADE,
+ FOREIGN KEY(keyword_id) REFERENCES context_keywords (id) ON DELETE CASCADE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+--
+-- Utilisateurs
+--
+
+CREATE TABLE users (
+ username VARCHAR(64) NOT NULL PRIMARY KEY,
+ level ENUM ('user', 'maintainer', 'admin') NOT NULL,
+ first_name VARCHAR(250) NOT NULL DEFAULT '',
+ last_name VARCHAR(250) NOT NULL DEFAULT '',
+ phone VARCHAR(250) NOT NULL DEFAULT '',
+ email VARCHAR(250) NOT NULL DEFAULT ''
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+--
+-- Séléctions
+--
+
+CREATE TABLE playlists (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ owner_username VARCHAR(250) NOT NULL,
+ name VARCHAR(250) NOT NULL,
+
+ FOREIGN KEY(owner_username) REFERENCES users (username) ON DELETE CASCADE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+CREATE TABLE playlist_resources (
+ playlist_id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ resource_type ENUM('item', 'collection') NOT NULL,
+ resource_id INTEGER NOT NULL,
+
+ FOREIGN KEY(playlist_id) REFERENCES playlists (id) ON DELETE CASCADE
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+
+
+--
+-- Historique des modifications
+--
+
+CREATE TABLE revisions (
+ id INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
+ element_type VARCHAR(32) NOT NULL,
+ element_id INTEGER NOT NULL,
+ change_type ENUM('create', 'update', 'delete') NOT NULL,
+ time DATETIME NOT NULL,
+ username VARCHAR(64) NOT NULL,
+
+ FOREIGN KEY(username) REFERENCES users (username)
+) CHARACTER SET='utf8' ENGINE=InnoDB;
+