venice-dynamo-rewrite/conf/db-init-mysql.sql

237 lines
7.3 KiB
MySQL
Raw Normal View History

2003-05-19 21:25:31 -06:00
# The contents of this file are subject to the Mozilla Public License Version 1.1
# (the "License"); you may not use this file except in compliance with the License.
# You may obtain a copy of the License at <http://www.mozilla.org/MPL/>.
#
# Software distributed under the License is distributed on an "AS IS" basis, WITHOUT
# WARRANTY OF ANY KIND, either express or implied. See the License for the specific
# language governing rights and limitations under the License.
#
# The Original Code is the Venice Web Communities System.
#
# The Initial Developer of the Original Code is Eric J. Bowersox <erbo@silcom.com>,
# for Silverwrist Design Studios. Portions created by Eric J. Bowersox are
# Copyright (C) 2003 Eric J. Bowersox/Silverwrist Design Studios. All Rights Reserved.
#
# Contributor(s):
#
##############################################################################
# Database Creation
##############################################################################
DROP DATABASE IF EXISTS dbname;
CREATE DATABASE dbname;
USE dbname;
##############################################################################
# Table Creation
##############################################################################
# The "namespace cache" table, used to map string namespaces (used in the code) to integer IDs
# (used in the database).
CREATE TABLE namespaces (
nsid INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
namespace VARCHAR(255) BINARY NOT NULL,
UNIQUE INDEX on_namespace (namespace)
);
# The global properties table.
CREATE TABLE globalprop (
nsid INT NOT NULL,
prop_name VARCHAR(255) BINARY NOT NULL,
prop_value VARCHAR(255),
PRIMARY KEY (nsid, prop_name)
);
# The global "blocks" table, used to store fragments of text/HTML for later use.
CREATE TABLE globalblock (
nsid INT NOT NULL,
block_name VARCHAR(255) BINARY NOT NULL,
block TEXT,
PRIMARY KEY (nsid, block_name)
);
# The main user information table.
CREATE TABLE users (
uid INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
username VARCHAR(64) NOT NULL,
email VARCHAR(255) NOT NULL,
is_anon TINYINT DEFAULT 0,
locked TINYINT DEFAULT 0,
nospam TINYINT DEFAULT 0,
created DATETIME NOT NULL,
last_accessed DATETIME,
UNIQUE INDEX on_username (username)
);
# The user authentication data table. We identify authentication methods by namespace ID
# and name, and provide "source data" to allow multiple sources for the same type of
# authentication (such as browser cookies for multiple browsers).
CREATE TABLE userauth (
uid INT NOT NULL,
nsid INT NOT NULL,
method VARCHAR(255) BINARY NOT NULL,
source_data VARCHAR(255),
auth_data VARCHAR(255),
PRIMARY KEY (uid, nsid, method)
);
# The user properties table.
CREATE TABLE userprop (
uid INT NOT NULL,
nsid INT NOT NULL,
prop_name VARCHAR(255) BINARY NOT NULL,
prop_value VARCHAR(255),
PRIMARY KEY (uid, nsid, prop_name)
);
# The groups table.
CREATE TABLE groups (
gid INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
groupname VARCHAR(64) NOT NULL,
gaclid INT NOT NULL DEFAULT -1,
UNIQUE INDEX on_groupname (groupname)
);
# The group membership table.
CREATE TABLE groupmembers (
gid INT NOT NULL,
uid INT NOT NULL,
PRIMARY KEY (gid, uid),
UNIQUE INDEX reverse_index (uid, gid)
);
# The group properties table.
CREATE TABLE groupprop (
gid INT NOT NULL,
nsid INT NOT NULL,
prop_name VARCHAR(255) BINARY NOT NULL,
prop_value VARCHAR(255),
PRIMARY KEY (gid, nsid, prop_name)
);
# The main ACL table. Each ACL has a numeric ID, a name, an unordered collection of owners (which may
# be groups or users), and an ordered collection of entries (ACEs).
CREATE TABLE acl (
aclid INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
aclname VARCHAR(255) NOT NULL,
INDEX on_name (aclname)
);
# The table of owners for ACLs. Each ACL has one or more owners.
# Flags Bit 0: 0=user, 1=group
CREATE TABLE aclowner (
aclid INT NOT NULL,
ownerid INT NOT NULL,
flags TINYINT NOT NULL,
INDEX on_acl (aclid)
);
# The table mapping ACLs to ACEs. Each ACL has zero or more ACEs.
CREATE TABLE acldata (
aclid INT NOT NULL,
seq INT NOT NULL,
aceid INT NOT NULL,
PRIMARY KEY (aclid, seq)
);
# The main ACE table. Each ACE has a numeric ID, a principal reference (which may be a user or
# group ID), a "negative" flag, and an unordered collection of permissions.
# Flags Bit 0: 0=user, 1=group
# Flags Bit 4: 0=positive ACE, 1=negative ACE
CREATE TABLE ace (
aceid INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
pri INT,
flags TINYINT NOT NULL DEFAULT 0
);
# The table mapping permissions into ACEs. Permissions are identified by namespace and name.
CREATE TABLE acedata (
aceid INT NOT NULL,
perm_nsid INT NOT NULL,
perm_name VARCHAR(255) BINARY NOT NULL,
INDEX on_ace (aceid)
);
# Global security data table.
CREATE TABLE globalsec (
admin_uid INT NOT NULL,
admin_gid INT NOT NULL,
global_aclid INT NOT NULL,
alluser_gid INT NOT NULL,
verified_gid INT NOT NULL
);
# The audit information table. Each audit "event" can have up to 8 properties defined with it,
# which are serialized as other "properties."
CREATE TABLE audit (
record BIGINT NOT NULL PRIMARY KEY AUTO_INCREMENT,
on_date DATETIME NOT NULL,
event INT NOT NULL,
uid INT NOT NULL,
subid INT NOT NULL DEFAULT 0,
ip VARCHAR(48),
prop0 VARCHAR(255),
prop1 VARCHAR(255),
prop2 VARCHAR(255),
prop3 VARCHAR(255),
prop4 VARCHAR(255),
prop5 VARCHAR(255),
prop6 VARCHAR(255),
prop7 VARCHAR(255),
INDEX by_date (on_date),
INDEX sub_view (subid, on_date)
);
# The table where events are assigned "event IDs" in the master audit record,
# to cut down on space usage in the audit table. Event IDs can be predefined
# at database create time, or defined dynamically, or both.
CREATE TABLE auditevent (
eventid INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
event_nsid INT NOT NULL,
event_name VARCHAR(255) BINARY NOT NULL,
descr TINYTEXT,
UNIQUE INDEX by_event (event_nsid, event_name)
);
# The image store table. This is used to store relatively small images like
# user photos and logos.
CREATE TABLE imagestore (
imageid INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
typecode INT NOT NULL,
ownerid INT NOT NULL,
ownerflag TINYINT NOT NULL DEFAULT 0,
mimetype VARCHAR(128),
length INT,
data MEDIUMBLOB
);
# The image type table, used to differentiate between images stored in the table.
CREATE TABLE imagetype (
typecode INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
nsid INT NOT NULL,
name VARCHAR(255) BINARY NOT NULL
);
##############################################################################
# Set table access rights
##############################################################################
# this is a test only - remove when we go to production
GRANT ALL PRIVILEGES ON dbname.*
TO erbo@localhost IDENTIFIED BY 'meesatest'
WITH GRANT OPTION;
GRANT ALL PRIVILEGES ON dbname.*
TO erbo@'10.29.99.%' IDENTIFIED BY 'meesatest'
WITH GRANT OPTION;
GRANT INSERT, DELETE, UPDATE, SELECT ON dbname.*
TO testuser@localhost IDENTIFIED BY 'TestPassword';
##############################################################################
# Initialization data
##############################################################################
INSERT INTO users (uid, username, email, is_anon, nospam, created)
VALUES (1, 'Anonymous_Honyak', 'nobody@localhost', 1, 1, '2002-12-15 12:00:00');