2 # 1) Create a database using the "CREATE DATABASE" mysql command.
3 # 2) Then, execute this script from command prompt with a command like this:
4 # mysql -h host -u user -p -D db_name < mysql.sql
6 # create database timetracker character set = 'utf8';
12 # Structure for table tt_teams. A team is a group of users for whom we are tracking work time.
13 # This table stores settings common to all team members such as language, week start day, etc.
15 CREATE TABLE `tt_teams` (
16 `id` int(11) NOT NULL auto_increment, # team id
17 `timestamp` timestamp NOT NULL, # modification timestamp
18 `name` varchar(80) default NULL, # team name
19 `address` varchar(255) default NULL, # team address, used in invoices
20 `currency` varchar(7) default NULL, # team currency symbol
21 `decimal_mark` char(1) NOT NULL default '.', # separator in decimals
22 `lang` varchar(10) NOT NULL default 'en', # language
23 `date_format` varchar(20) NOT NULL default '%Y-%m-%d', # date format
24 `time_format` varchar(20) NOT NULL default '%H:%M', # time format
25 `week_start` smallint(2) NOT NULL DEFAULT '0', # Week start day, 0 == Sunday.
26 `tracking_mode` smallint(2) NOT NULL DEFAULT '1', # tracking mode ("projects" or "projects and tasks")
27 `record_type` smallint(2) NOT NULL DEFAULT '0', # time record type ("start and finish", "duration", or both)
28 `uncompleted_indicators` smallint(2) NOT NULL DEFAULT '0', # show indicator for users with uncompleted time entries
29 `plugins` varchar(255) default NULL, # a list of enabled plugins for team
30 `lock_spec` varchar(255) default NULL, # Cron specification for record locking,
31 # for example: "0 10 * * 1" for "weekly on Mon at 10:00".
32 `workday_hours` smallint(6) DEFAULT '8', # number of work hours in a regular day
33 `custom_logo` tinyint(4) default '0', # whether to use a custom logo or not
34 `status` tinyint(4) default '1', # team status
40 # Structure for table tt_users. This table is used to store user properties.
42 CREATE TABLE `tt_users` (
43 `id` int(11) NOT NULL auto_increment, # user id
44 `timestamp` timestamp NOT NULL, # modification timestamp
45 `login` varchar(50) COLLATE utf8_bin NOT NULL, # user login
46 `password` varchar(50) default NULL, # password hash
47 `name` varchar(100) default NULL, # user name
48 `team_id` int(11) NOT NULL, # team id
49 `role` int(11) default '4', # user role ("manager", "co-manager", "client", or "user")
50 `client_id` int(11) default NULL, # client id for "client" user role
51 `rate` float(6,2) NOT NULL default '0.00', # default hourly rate
52 `email` varchar(100) default NULL, # user email
53 `status` tinyint(4) default '1', # user status
57 # Create an index that guarantees unique active and inactive logins.
58 create unique index login_idx on tt_users(login, status);
60 # Create admin account with password 'secret'. Admin is a superuser, who can create teams.
61 DELETE from `tt_users` WHERE login = 'admin';
62 INSERT INTO `tt_users` (`login`, `password`, `name`, `team_id`, `role`) VALUES ('admin', md5('secret'), 'Admin', '0', '1024');
66 # Structure for table tt_projects.
68 CREATE TABLE `tt_projects` (
69 `id` int(11) NOT NULL auto_increment, # project id
70 `team_id` int(11) NOT NULL, # team id
71 `name` varchar(80) COLLATE utf8_bin NOT NULL, # project name
72 `description` varchar(255) default NULL, # project description
73 `tasks` text default NULL, # comma-separated list of task ids associated with this project
74 `status` tinyint(4) default '1', # project status
78 # Create an index that guarantees unique active and inactive projects per team.
79 create unique index project_idx on tt_projects(team_id, name, status);
83 # Structure for table tt_tasks.
85 CREATE TABLE `tt_tasks` (
86 `id` int(11) NOT NULL auto_increment, # task id
87 `team_id` int(11) NOT NULL, # team id
88 `name` varchar(80) COLLATE utf8_bin NOT NULL, # task name
89 `description` varchar(255) default NULL, # task description
90 `status` tinyint(4) default '1', # task status
94 # Create an index that guarantees unique active and inactive tasks per team.
95 create unique index task_idx on tt_tasks(team_id, name, status);
99 # Structure for table tt_user_project_binds. This table maps users to assigned projects.
101 CREATE TABLE `tt_user_project_binds` (
102 `id` int(11) NOT NULL auto_increment, # bind id
103 `user_id` int(11) NOT NULL, # user id
104 `project_id` int(11) NOT NULL, # project id
105 `rate` float(6,2) default '0.00', # rate for this user when working on this project
106 `status` tinyint(4) default '1', # bind status
110 # Create an index that guarantees unique user to project binds.
111 create unique index bind_idx on tt_user_project_binds(user_id, project_id);
115 # Structure for table tt_project_task_binds. This table maps projects to assigned tasks.
117 CREATE TABLE `tt_project_task_binds` (
118 `project_id` int(11) NOT NULL, # project id
119 `task_id` int(11) NOT NULL # task id
122 # Indexes for tt_project_task_binds.
123 create index project_idx on tt_project_task_binds(project_id);
124 create index task_idx on tt_project_task_binds(task_id);
128 # Structure for table tt_log. This is the table where time entries for users are stored.
129 # If you use custom fields, additional info for each record may exist in tt_custom_field_log.
131 CREATE TABLE `tt_log` (
132 `id` bigint NOT NULL auto_increment, # time record id
133 `timestamp` timestamp NOT NULL, # modification timestamp
134 `user_id` int(11) NOT NULL, # user id
135 `date` date NOT NULL, # date the record is for
136 `start` time default NULL, # record start time (for example, 09:00)
137 `duration` time default NULL, # record duration (for example, 1 hour)
138 `client_id` int(11) default NULL, # client id
139 `project_id` int(11) default NULL, # project id
140 `task_id` int(11) default NULL, # task id
141 `invoice_id` int(11) default NULL, # invoice id
142 `comment` blob, # user provided comment for time record
143 `billable` tinyint(4) default '0', # whether the record is billable or not
144 `status` tinyint(4) default '1', # time record status
148 # Create indexes on tt_log for performance.
149 create index date_idx on tt_log(date);
150 create index user_idx on tt_log(user_id);
151 create index client_idx on tt_log(client_id);
152 create index invoice_idx on tt_log(invoice_id);
153 create index project_idx on tt_log(project_id);
154 create index task_idx on tt_log(task_id);
158 # Structure for table tt_invoices. Invoices are issued to clients for billable work.
160 CREATE TABLE `tt_invoices` (
161 `id` int(11) NOT NULL auto_increment, # invoice id
162 `team_id` int(11) NOT NULL, # team id
163 `name` varchar(80) COLLATE utf8_bin NOT NULL, # invoice name
164 `date` date NOT NULL, # invoice date
165 `client_id` int(11) NOT NULL, # client id
166 `status` tinyint(4) default '1', # invoice status
170 # Create an index that guarantees unique invoice names per team.
171 create unique index name_idx on tt_invoices(team_id, name, status);
175 # Structure for table tt_tmp_refs. Used for reset password mechanism.
177 CREATE TABLE `tt_tmp_refs` (
178 `timestamp` timestamp NOT NULL, # creation timestamp
179 `ref` char(32) NOT NULL default '', # unique reference for user, used in urls
180 `user_id` int(11) NOT NULL # user id
185 # Structure for table tt_fav_reports. Favorite reports are pre-configured report configurations.
187 CREATE TABLE `tt_fav_reports` (
188 `id` int(11) NOT NULL auto_increment, # favorite report id
189 `name` varchar(200) NOT NULL, # favorite report name
190 `user_id` int(11) NOT NULL, # user id favorite report belongs to
191 `client_id` int(11) default NULL, # client id (if selected)
192 `cf_1_option_id` int(11) default NULL, # custom field 1 option id (if selected)
193 `project_id` int(11) default NULL, # project id (if selected)
194 `task_id` int(11) default NULL, # task id (if selected)
195 `billable` tinyint(4) default NULL, # whether to include billable, not billable, or all records
196 `invoice` tinyint(4) default NULL, # whether to include invoiced, not invoiced, or all records
197 `users` text default NULL, # Comma-separated list of user ids. Nothing here means "all" users.
198 `period` tinyint(4) default NULL, # selected period type for report
199 `period_start` date default NULL, # period start
200 `period_end` date default NULL, # period end
201 `show_client` tinyint(4) NOT NULL default '0', # whether to show client column
202 `show_invoice` tinyint(4) NOT NULL default '0', # whether to show invoice column
203 `show_project` tinyint(4) NOT NULL default '0', # whether to show project column
204 `show_start` tinyint(4) NOT NULL default '0', # whether to show start field
205 `show_duration` tinyint(4) NOT NULL default '0', # whether to show duration field
206 `show_cost` tinyint(4) NOT NULL default '0', # whether to show cost field
207 `show_task` tinyint(4) NOT NULL default '0', # whether to show task column
208 `show_end` tinyint(4) NOT NULL default '0', # whether to show end field
209 `show_note` tinyint(4) NOT NULL default '0', # whether to show note column
210 `show_custom_field_1` tinyint(4) NOT NULL default '0', # whether to show custom field 1
211 `show_totals_only` tinyint(4) NOT NULL default '0', # whether to show totals only
212 `group_by` varchar(20) default NULL, # group by field
218 # Structure for table tt_cron. It is used to email favorite reports on schedule.
220 CREATE TABLE `tt_cron` (
221 `id` int(11) NOT NULL auto_increment, # entry id
222 `team_id` int(11) NOT NULL, # team id
223 `cron_spec` varchar(255) NOT NULL, # cron specification, "0 1 * * *" for "daily at 01:00"
224 `last` int(11) default NULL, # UNIX timestamp of when job was last run
225 `next` int(11) default NULL, # UNIX timestamp of when to run next job
226 `report_id` int(11) default NULL, # report id from tt_fav_reports, a report to mail on schedule
227 `email` varchar(100) default NULL, # email to send results to
228 `status` tinyint(4) default '1', # entry status
234 # Structure for table tt_clients. A client is an entity for whom work is performed and who may be invoiced.
236 CREATE TABLE `tt_clients` (
237 `id` int(11) NOT NULL AUTO_INCREMENT, # client id
238 `team_id` int(11) NOT NULL, # team id
239 `name` varchar(80) COLLATE utf8_bin NOT NULL, # client name
240 `address` varchar(255) default NULL, # client address
241 `tax` float(6,2) default '0.00', # applicable tax for this client
242 `projects` text default NULL, # comma-separated list of project ids assigned to this client
243 `status` tinyint(4) default '1', # client status
247 # Create an index that guarantees unique active and inactive clients per team.
248 create unique index client_name_idx on tt_clients(team_id, name, status);
252 # Structure for table tt_client_project_binds. This table maps clients to assigned projects.
254 CREATE TABLE `tt_client_project_binds` (
255 `client_id` int(11) NOT NULL, # client id
256 `project_id` int(11) NOT NULL # project id
259 # Indexes for tt_client_project_binds.
260 create index client_idx on tt_client_project_binds(client_id);
261 create index project_idx on tt_client_project_binds(project_id);
265 # Structure for table tt_config. This table is used to store configuration info for users.
266 # For example, last_report_email parameter stores an email for user last report was emailed to.
268 CREATE TABLE `tt_config` (
269 `user_id` int(11) NOT NULL, # user id
270 `param_name` varchar(32) NOT NULL, # parameter name
271 `param_value` varchar(80) default NULL # parameter value
274 # Create an index that guarantees unique parameter names per user.
275 create unique index param_idx on tt_config(user_id, param_name);
278 # Below are the tables used by CustomFields plugin.
281 # Structure for table tt_custom_fields. This table contains definitions of custom fields.
283 CREATE TABLE `tt_custom_fields` (
284 `id` int(11) NOT NULL auto_increment, # custom field id
285 `team_id` int(11) NOT NULL, # team id
286 `type` tinyint(4) NOT NULL default '0', # custom field type (text or dropdown)
287 `label` varchar(32) NOT NULL default '', # custom field label
288 `required` tinyint(4) default '0', # whether this custom field is mandatory for time records
289 `status` tinyint(4) default '1', # custom field status
295 # Structure for table tt_custom_field_options. This table defines options for dropdown custom fields.
297 CREATE TABLE `tt_custom_field_options` (
298 `id` int(11) NOT NULL auto_increment, # option id
299 `field_id` int(11) NOT NULL, # custom field id
300 `value` varchar(32) NOT NULL default '', # option value
306 # Structure for table tt_custom_field_log.
307 # This table supplements tt_log and contains custom field values for records.
309 CREATE TABLE `tt_custom_field_log` (
310 `id` bigint NOT NULL auto_increment, # cutom field log id
311 `log_id` bigint NOT NULL, # id of a record in tt_log this record corresponds to
312 `field_id` int(11) NOT NULL, # custom field id
313 `option_id` int(11) default NULL, # Option id. Used for dropdown custom fields.
314 `value` varchar(255) default NULL, # Text value. Used for text custom fields.
315 `status` tinyint(4) default '1', # custom field log entry status
321 # Structure for table tt_expense_items.
322 # This table lists expense items.
324 CREATE TABLE `tt_expense_items` (
325 `id` bigint NOT NULL auto_increment, # expense item id
326 `date` date NOT NULL, # date the record is for
327 `user_id` int(11) NOT NULL, # user id the expense item is reported by
328 `client_id` int(11) default NULL, # client id
329 `project_id` int(11) default NULL, # project id
330 `name` text NOT NULL, # expense item name (what is an expense for)
331 `cost` decimal(10,2) default '0.00', # item cost (including taxes, etc.)
332 `invoice_id` int(11) default NULL, # invoice id
333 `status` tinyint(4) default '1', # item status
337 # Create indexes on tt_expense_items for performance.
338 create index date_idx on tt_expense_items(date);
339 create index user_idx on tt_expense_items(user_id);
340 create index client_idx on tt_expense_items(client_id);
341 create index project_idx on tt_expense_items(project_id);
342 create index invoice_idx on tt_expense_items(invoice_id);
346 # Structure for table tt_monthly_quotas.
347 # This table keeps monthly work hour quotas for teams.
349 CREATE TABLE `tt_monthly_quotas` (
350 `team_id` int(11) NOT NULL, # team id
351 `year` smallint(5) UNSIGNED NOT NULL, # quota year
352 `month` tinyint(3) UNSIGNED NOT NULL, # quota month
353 `quota` smallint(5) UNSIGNED NOT NULL, # number of work hours in specified month and year
354 PRIMARY KEY (`team_id`,`year`,`month`)
357 ALTER TABLE `tt_monthly_quotas`
358 ADD CONSTRAINT `FK_TT_TEAM_CONSTRAING` FOREIGN KEY (`team_id`) REFERENCES `tt_teams` (`id`) ON DELETE CASCADE ON UPDATE CASCADE;