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 = 'utf8mb4';
12 # Structure for table tt_groups. A group is a unit of users for whom we are tracking work time.
13 # This table stores settings common to all group members such as language, week start day, etc.
15 CREATE TABLE `tt_groups` (
16 `id` int(11) NOT NULL auto_increment, # group id
17 `parent_id` int(11) default NULL, # parent group id
18 `org_id` int(11) default NULL, # organization id (id of top group)
19 `name` varchar(80) default NULL, # group name
20 `description` varchar(255) default NULL, # group description
21 `currency` varchar(7) default NULL, # currency symbol
22 `decimal_mark` char(1) NOT NULL default '.', # separator in decimals
23 `lang` varchar(10) NOT NULL default 'en', # language
24 `date_format` varchar(20) NOT NULL default '%Y-%m-%d', # date format
25 `time_format` varchar(20) NOT NULL default '%H:%M', # time format
26 `week_start` smallint(2) NOT NULL default 0, # Week start day, 0 == Sunday.
27 `tracking_mode` smallint(2) NOT NULL default 1, # tracking mode ("time", "projects" or "projects and tasks")
28 `project_required` smallint(2) NOT NULL default 0, # whether a project selection is required or optional
29 `task_required` smallint(2) NOT NULL default 0, # whether a task selection is required or optional
30 `record_type` smallint(2) NOT NULL default 0, # time record type ("start and finish", "duration", or both)
31 `bcc_email` varchar(100) default NULL, # bcc email to copy all reports to
32 `allow_ip` varchar(255) default NULL, # specification from where users are allowed access
33 `password_complexity` varchar(64) default NULL, # password example that defines required complexity
34 `plugins` varchar(255) default NULL, # a list of enabled plugins for group
35 `lock_spec` varchar(255) default NULL, # Cron specification for record locking,
36 # for example: "0 10 * * 1" for "weekly on Mon at 10:00".
37 `workday_minutes` smallint(4) default 480, # number of work minutes in a regular working day
38 `custom_logo` tinyint(4) default 0, # whether to use a custom logo or not
39 `config` text default NULL, # miscellaneous group configuration settings
40 `created` datetime default NULL, # creation timestamp
41 `created_ip` varchar(45) default NULL, # creator ip
42 `created_by` int(11) default NULL, # creator user_id
43 `modified` datetime default NULL, # modification timestamp
44 `modified_ip` varchar(45) default NULL, # modifier ip
45 `modified_by` int(11) default NULL, # modifier user_id
46 `status` tinyint(4) default 1, # group status
52 # Structure for table tt_roles. This table stores group roles.
54 CREATE TABLE `tt_roles` (
55 `id` int(11) NOT NULL auto_increment, # Role id. Identifies roles for all groups on the server.
56 `group_id` int(11) NOT NULL, # Group id the role is defined for.
57 `org_id` int(11) default NULL, # Organization id.
58 `name` varchar(80) default NULL, # Role name - custom role name. In case we are editing a
59 # predefined role (USER, etc.), we can rename the role here.
60 `description` varchar(255) default NULL, # Role description.
61 `rank` int(11) default 0, # Role rank, an integer value between 0-512. Predefined role ranks:
62 # User - 4, Supervisor - 12, Client - 16,
63 # Co-manager - 68, Manager - 324, Top manager - 512.
64 # Rank is used to determine what "lesser roles" are in each group
65 # for situations such as "manage_users".
66 `rights` text default NULL, # Comma-separated list of rights assigned to a role.
67 # NULL here for predefined roles (4, 16, 68, 324 - manager)
68 # means a hard-coded set of default access rights.
69 `status` tinyint(4) default 1, # Role status.
73 # Create an index that guarantees unique active and inactive role ranks in each group.
74 create unique index role_idx on tt_roles(group_id, rank, status);
76 # Insert site-wide roles - site administrator and top manager.
77 INSERT INTO `tt_roles` (`group_id`, `name`, `rank`, `rights`) VALUES (0, 'Site administrator', 1024, 'administer_site');
78 INSERT INTO `tt_roles` (`group_id`, `name`, `rank`, `rights`) VALUES (0, 'Top manager', 512, 'track_own_time,track_own_expenses,view_own_reports,view_own_timesheets,manage_own_timesheets,view_own_charts,view_own_projects,view_own_tasks,manage_own_settings,view_users,view_client_reports,view_client_timesheets,view_client_unapproved,view_client_invoices,track_time,track_expenses,view_reports,view_timesheets,manage_timesheets,approve_timesheets,view_charts,view_own_clients,override_punch_mode,override_own_punch_mode,override_date_lock,override_own_date_lock,swap_roles,manage_own_account,manage_users,manage_projects,manage_tasks,manage_custom_fields,manage_clients,manage_invoices,override_allow_ip,manage_basic_settings,view_all_reports,view_all_timesheets,manage_all_timesheets,manage_features,manage_advanced_settings,manage_roles,export_data,approve_all_timesheets,manage_subgroups,delete_group');
82 # Structure for table tt_users. This table is used to store user properties.
84 CREATE TABLE `tt_users` (
85 `id` int(11) NOT NULL auto_increment, # user id
86 `login` varchar(50) COLLATE utf8mb4_bin NOT NULL,# user login
87 `password` varchar(50) default NULL, # password hash
88 `name` varchar(100) default NULL, # user name
89 `group_id` int(11) NOT NULL, # group id
90 `org_id` int(11) default NULL, # organization id
91 `role_id` int(11) default NULL, # role id
92 `client_id` int(11) default NULL, # client id for "client" user role
93 `rate` float(6,2) NOT NULL default '0.00', # default hourly rate
94 `quota_percent` float(6,2) NOT NULL default '100.00', # percent of time quota
95 `email` varchar(100) default NULL, # user email
96 `created` datetime default NULL, # creation timestamp
97 `created_ip` varchar(45) default NULL, # creator ip
98 `created_by` int(11) default NULL, # creator user_id (null for self)
99 `modified` datetime default NULL, # modification timestamp
100 `modified_ip` varchar(45) default NULL, # modifier ip
101 `modified_by` int(11) default NULL, # modifier user_id
102 `accessed` datetime default NULL, # last access timestamp
103 `accessed_ip` varchar(45) default NULL, # last access ip
104 `status` tinyint(4) default 1, # user status
108 # Create an index that guarantees unique active and inactive logins.
109 create unique index login_idx on tt_users(login, status);
111 # Create admin account with password 'secret'. Admin is a superuser who can create groups.
112 DELETE from `tt_users` WHERE login = 'admin';
113 INSERT INTO `tt_users` (`login`, `password`, `name`, `group_id`, `role_id`) VALUES ('admin', md5('secret'), 'Admin', '0', (select id from tt_roles where rank = 1024));
117 # Structure for table tt_projects.
119 CREATE TABLE `tt_projects` (
120 `id` int(11) NOT NULL auto_increment, # project id
121 `group_id` int(11) NOT NULL, # group id
122 `org_id` int(11) default NULL, # organization id
123 `name` varchar(80) COLLATE utf8mb4_bin NOT NULL, # project name
124 `description` varchar(255) default NULL, # project description
125 `tasks` text default NULL, # comma-separated list of task ids associated with this project
126 `status` tinyint(4) default 1, # project status
130 # Create an index that guarantees unique active and inactive projects per group.
131 create unique index project_idx on tt_projects(group_id, name, status);
135 # Structure for table tt_tasks.
137 CREATE TABLE `tt_tasks` (
138 `id` int(11) NOT NULL auto_increment, # task id
139 `group_id` int(11) NOT NULL, # group id
140 `org_id` int(11) default NULL, # organization id
141 `name` varchar(80) COLLATE utf8mb4_bin NOT NULL, # task name
142 `description` varchar(255) default NULL, # task description
143 `status` tinyint(4) default 1, # task status
147 # Create an index that guarantees unique active and inactive tasks per group.
148 create unique index task_idx on tt_tasks(group_id, name, status);
152 # Structure for table tt_user_project_binds. This table maps users to assigned projects.
154 CREATE TABLE `tt_user_project_binds` (
155 `id` int(11) NOT NULL auto_increment, # bind id
156 `user_id` int(11) NOT NULL, # user id
157 `project_id` int(11) NOT NULL, # project id
158 `group_id` int(11) default NULL, # group id
159 `org_id` int(11) default NULL, # organization id
160 `rate` float(6,2) default '0.00', # rate for this user when working on this project
161 `status` tinyint(4) default 1, # bind status
165 # Create an index that guarantees unique user to project binds.
166 create unique index bind_idx on tt_user_project_binds(user_id, project_id);
170 # Structure for table tt_project_task_binds. This table maps projects to assigned tasks.
172 CREATE TABLE `tt_project_task_binds` (
173 `project_id` int(11) NOT NULL, # project id
174 `task_id` int(11) NOT NULL, # task id
175 `group_id` int(11) default NULL, # group id
176 `org_id` int(11) default NULL # organization id
179 # Indexes for tt_project_task_binds.
180 create index project_idx on tt_project_task_binds(project_id);
181 create index task_idx on tt_project_task_binds(task_id);
182 create unique index project_task_idx on tt_project_task_binds(project_id, task_id);
186 # Structure for table tt_log. This is the table where time entries for users are stored.
187 # If you use custom fields, additional info for each record may exist in tt_custom_field_log.
189 CREATE TABLE `tt_log` (
190 `id` bigint NOT NULL auto_increment, # time record id
191 `user_id` int(11) NOT NULL, # user id
192 `group_id` int(11) default NULL, # group id
193 `org_id` int(11) default NULL, # organization id
194 `date` date NOT NULL, # date the record is for
195 `start` time default NULL, # record start time (for example, 09:00)
196 `duration` time default NULL, # record duration (for example, 1 hour)
197 `client_id` int(11) default NULL, # client id
198 `project_id` int(11) default NULL, # project id
199 `task_id` int(11) default NULL, # task id
200 `timesheet_id` int(11) default NULL, # timesheet id
201 `invoice_id` int(11) default NULL, # invoice id
202 `comment` text, # user provided comment for time record
203 `billable` tinyint(4) default 0, # whether the record is billable or not
204 `approved` tinyint(4) default 0, # whether the record is approved
205 `paid` tinyint(4) default 0, # whether the record is paid
206 `created` datetime default NULL, # creation timestamp
207 `created_ip` varchar(45) default NULL, # creator ip
208 `created_by` int(11) default NULL, # creator user_id
209 `modified` datetime default NULL, # modification timestamp
210 `modified_ip` varchar(45) default NULL, # modifier ip
211 `modified_by` int(11) default NULL, # modifier user_id
212 `status` tinyint(4) default 1, # time record status
216 # Create indexes on tt_log for performance.
217 create index date_idx on tt_log(date);
218 create index user_idx on tt_log(user_id);
219 create index group_idx on tt_log(group_id);
220 create index client_idx on tt_log(client_id);
221 create index invoice_idx on tt_log(invoice_id);
222 create index project_idx on tt_log(project_id);
223 create index task_idx on tt_log(task_id);
224 create index timesheet_idx on tt_log(timesheet_id);
228 # Structure for table tt_invoices. Invoices are issued to clients for billable work.
230 CREATE TABLE `tt_invoices` (
231 `id` int(11) NOT NULL auto_increment, # invoice id
232 `group_id` int(11) NOT NULL, # group id
233 `org_id` int(11) default NULL, # organization id
234 `name` varchar(80) COLLATE utf8mb4_bin NOT NULL, # invoice name
235 `date` date NOT NULL, # invoice date
236 `client_id` int(11) NOT NULL, # client id
237 `status` tinyint(4) default 1, # invoice status
241 # Create an index that guarantees unique invoice names per group.
242 create unique index name_idx on tt_invoices(group_id, name, status);
246 # Structure for table tt_tmp_refs. Used for reset password mechanism.
248 CREATE TABLE `tt_tmp_refs` (
249 `created` datetime default NULL, # creation timestamp
250 `ref` char(32) NOT NULL default '', # unique reference for user, used in urls
251 `user_id` int(11) NOT NULL # user id
256 # Structure for table tt_fav_reports. Favorite reports are pre-configured report configurations.
258 CREATE TABLE `tt_fav_reports` (
259 `id` int(11) NOT NULL auto_increment, # favorite report id
260 `name` varchar(200) NOT NULL, # favorite report name
261 `user_id` int(11) NOT NULL, # user id favorite report belongs to
262 `group_id` int(11) default NULL, # group id
263 `org_id` int(11) default NULL, # organization id
264 `report_spec` text default NULL, # future replacement field for all report settings
265 `client_id` int(11) default NULL, # client id (if selected)
266 `cf_1_option_id` int(11) default NULL, # custom field 1 option id (if selected)
267 `project_id` int(11) default NULL, # project id (if selected)
268 `task_id` int(11) default NULL, # task id (if selected)
269 `billable` tinyint(4) default NULL, # whether to include billable, not billable, or all records
270 `invoice` tinyint(4) default NULL, # whether to include invoiced, not invoiced, or all records
271 `paid_status` tinyint(4) default NULL, # whether to include paid, not paid, or all records
272 `users` text default NULL, # Comma-separated list of user ids. Nothing here means "all" users.
273 `period` tinyint(4) default NULL, # selected period type for report
274 `period_start` date default NULL, # period start
275 `period_end` date default NULL, # period end
276 `show_client` tinyint(4) NOT NULL default 0, # whether to show client column
277 `show_invoice` tinyint(4) NOT NULL default 0, # whether to show invoice column
278 `show_paid` tinyint(4) NOT NULL default 0, # whether to show paid column
279 `show_ip` tinyint(4) NOT NULL default 0, # whether to show ip column
280 `show_project` tinyint(4) NOT NULL default 0, # whether to show project column
281 `show_start` tinyint(4) NOT NULL default 0, # whether to show start field
282 `show_duration` tinyint(4) NOT NULL default 0, # whether to show duration field
283 `show_cost` tinyint(4) NOT NULL default 0, # whether to show cost field
284 `show_task` tinyint(4) NOT NULL default 0, # whether to show task column
285 `show_end` tinyint(4) NOT NULL default 0, # whether to show end field
286 `show_note` tinyint(4) NOT NULL default 0, # whether to show note column
287 `show_custom_field_1` tinyint(4) NOT NULL default 0, # whether to show custom field 1
288 `show_work_units` tinyint(4) NOT NULL default 0, # whether to show work units
289 `show_totals_only` tinyint(4) NOT NULL default 0, # whether to show totals only
290 `group_by1` varchar(20) default NULL, # group by field 1
291 `group_by2` varchar(20) default NULL, # group by field 2
292 `group_by3` varchar(20) default NULL, # group by field 3
293 `status` tinyint(4) default 1, # favorite report status
299 # Structure for table tt_cron. It is used to email favorite reports on schedule.
301 CREATE TABLE `tt_cron` (
302 `id` int(11) NOT NULL auto_increment, # entry id
303 `group_id` int(11) NOT NULL, # group id
304 `org_id` int(11) default NULL, # organization id
305 `cron_spec` varchar(255) NOT NULL, # cron specification, "0 1 * * *" for "daily at 01:00"
306 `last` int(11) default NULL, # UNIX timestamp of when job was last run
307 `next` int(11) default NULL, # UNIX timestamp of when to run next job
308 `report_id` int(11) default NULL, # report id from tt_fav_reports, a report to mail on schedule
309 `email` varchar(100) default NULL, # email to send results to
310 `cc` varchar(100) default NULL, # cc email to send results to
311 `subject` varchar(100) default NULL, # email subject
312 `report_condition` varchar(255) default NULL, # report condition, "count > 0" for sending not empty reports
313 `status` tinyint(4) default 1, # entry status
319 # Structure for table tt_clients. A client is an entity for whom work is performed and who may be invoiced.
321 CREATE TABLE `tt_clients` (
322 `id` int(11) NOT NULL AUTO_INCREMENT, # client id
323 `group_id` int(11) NOT NULL, # group id
324 `org_id` int(11) default NULL, # organization id
325 `name` varchar(80) COLLATE utf8mb4_bin NOT NULL, # client name
326 `address` varchar(255) default NULL, # client address
327 `tax` float(6,2) default '0.00', # applicable tax for this client
328 `projects` text default NULL, # comma-separated list of project ids assigned to this client
329 `status` tinyint(4) default 1, # client status
333 # Create an index that guarantees unique active and inactive clients per group.
334 create unique index client_name_idx on tt_clients(group_id, name, status);
338 # Structure for table tt_client_project_binds. This table maps clients to assigned projects.
340 CREATE TABLE `tt_client_project_binds` (
341 `client_id` int(11) NOT NULL, # client id
342 `project_id` int(11) NOT NULL, # project id
343 `group_id` int(11) default NULL, # group id
344 `org_id` int(11) default NULL # organization id
347 # Indexes for tt_client_project_binds.
348 create index client_idx on tt_client_project_binds(client_id);
349 create index project_idx on tt_client_project_binds(project_id);
350 create unique index client_project_idx on tt_client_project_binds(client_id, project_id);
354 # Structure for table tt_config. This table is used to store configuration info for users.
355 # For example, last_report_email parameter stores an email for user last report was emailed to.
357 CREATE TABLE `tt_config` (
358 `user_id` int(11) NOT NULL, # user id
359 `group_id` int(11) default NULL, # group id
360 `org_id` int(11) default NULL, # organization id
361 `param_name` varchar(32) NOT NULL, # parameter name
362 `param_value` varchar(80) default NULL # parameter value
365 # Create an index that guarantees unique parameter names per user.
366 create unique index param_idx on tt_config(user_id, param_name);
369 # Below are the tables used by CustomFields plugin.
372 # Structure for table tt_custom_fields. This table contains definitions of custom fields.
374 CREATE TABLE `tt_custom_fields` (
375 `id` int(11) NOT NULL auto_increment, # custom field id
376 `group_id` int(11) NOT NULL, # group id
377 `org_id` int(11) default NULL, # organization id
378 `type` tinyint(4) NOT NULL default 0, # custom field type (text or dropdown)
379 `label` varchar(32) NOT NULL default '', # custom field label
380 `required` tinyint(4) default 0, # whether this custom field is mandatory for time records
381 `status` tinyint(4) default 1, # custom field status
387 # Structure for table tt_custom_field_options. This table defines options for dropdown custom fields.
389 CREATE TABLE `tt_custom_field_options` (
390 `id` int(11) NOT NULL auto_increment, # option id
391 `group_id` int(11) default NULL, # group id
392 `org_id` int(11) default NULL, # organization id
393 `field_id` int(11) NOT NULL, # custom field id
394 `value` varchar(32) NOT NULL default '', # option value
395 `status` tinyint(4) default 1, # option status
401 # Structure for table tt_custom_field_log.
402 # This table supplements tt_log and contains custom field values for records.
404 CREATE TABLE `tt_custom_field_log` (
405 `id` bigint NOT NULL auto_increment, # custom field log id
406 `group_id` int(11) default NULL, # group id
407 `org_id` int(11) default NULL, # organization id
408 `log_id` bigint NOT NULL, # id of a record in tt_log this record corresponds to
409 `field_id` int(11) NOT NULL, # custom field id
410 `option_id` int(11) default NULL, # Option id. Used for dropdown custom fields.
411 `value` varchar(255) default NULL, # Text value. Used for text custom fields.
412 `status` tinyint(4) default 1, # custom field log entry status
416 create index log_idx on tt_custom_field_log(log_id);
420 # Structure for table tt_expense_items.
421 # This table lists expense items.
423 CREATE TABLE `tt_expense_items` (
424 `id` bigint NOT NULL auto_increment, # expense item id
425 `date` date NOT NULL, # date the record is for
426 `user_id` int(11) NOT NULL, # user id the expense item is reported by
427 `group_id` int(11) default NULL, # group id
428 `org_id` int(11) default NULL, # organization id
429 `client_id` int(11) default NULL, # client id
430 `project_id` int(11) default NULL, # project id
431 `timesheet_id` int(11) default NULL, # timesheet id
432 `name` text NOT NULL, # expense item name (what is an expense for)
433 `cost` decimal(10,2) default '0.00', # item cost (including taxes, etc.)
434 `invoice_id` int(11) default NULL, # invoice id
435 `approved` tinyint(4) default 0, # whether the item is approved
436 `paid` tinyint(4) default 0, # whether the item is paid
437 `created` datetime default NULL, # creation timestamp
438 `created_ip` varchar(45) default NULL, # creator ip
439 `created_by` int(11) default NULL, # creator user_id
440 `modified` datetime default NULL, # modification timestamp
441 `modified_ip` varchar(45) default NULL, # modifier ip
442 `modified_by` int(11) default NULL, # modifier user_id
443 `status` tinyint(4) default 1, # item status
447 # Create indexes on tt_expense_items for performance.
448 create index date_idx on tt_expense_items(date);
449 create index user_idx on tt_expense_items(user_id);
450 create index group_idx on tt_expense_items(group_id);
451 create index client_idx on tt_expense_items(client_id);
452 create index project_idx on tt_expense_items(project_id);
453 create index timesheet_idx on tt_expense_items(timesheet_id);
454 create index invoice_idx on tt_expense_items(invoice_id);
458 # Structure for table tt_predefined_expenses.
459 # This table keeps names and costs for predefined expenses.
461 CREATE TABLE `tt_predefined_expenses` (
462 `id` int(11) NOT NULL auto_increment, # predefined expense id
463 `group_id` int(11) NOT NULL, # group id
464 `org_id` int(11) default NULL, # organization id
465 `name` varchar(255) NOT NULL, # predefined expense name, such as mileage
466 `cost` decimal(10,2) default '0.00', # cost for one unit
472 # Structure for table tt_monthly_quotas.
473 # This table keeps monthly work hour quotas for groups.
475 CREATE TABLE `tt_monthly_quotas` (
476 `group_id` int(11) NOT NULL, # group id
477 `org_id` int(11) default NULL, # organization id
478 `year` smallint(5) UNSIGNED NOT NULL, # quota year
479 `month` tinyint(3) UNSIGNED NOT NULL, # quota month
480 `minutes` int(11) default NULL, # quota in minutes in specified month and year
481 PRIMARY KEY (`group_id`,`year`,`month`)
486 # Structure for table tt_timesheets. This table keeps timesheet related information.
488 CREATE TABLE `tt_timesheets` (
489 `id` int(11) NOT NULL auto_increment, # timesheet id
490 `user_id` int(11) NOT NULL, # user id
491 `group_id` int(11) default NULL, # group id
492 `org_id` int(11) default NULL, # organization id
493 `client_id` int(11) default NULL, # client id
494 `name` varchar(80) COLLATE utf8mb4_bin NOT NULL, # timesheet name
495 `submit_status` tinyint(4) default NULL, # submit status
496 `submitter_comment` text, # submitter comment
497 `approval_status` tinyint(4) default NULL, # approval status
498 `manager_comment` text, # manager comment
499 `created` datetime default NULL, # creation timestamp
500 `created_ip` varchar(45) default NULL, # creator ip
501 `created_by` int(11) default NULL, # creator user_id
502 `modified` datetime default NULL, # modification timestamp
503 `modified_ip` varchar(45) default NULL, # modifier ip
504 `modified_by` int(11) default NULL, # modifier user_id
505 `status` tinyint(4) default 1, # timesheet status
511 # Structure for table tt_site_config. This table stores configuration data
512 # for Time Tracker site as a whole.
513 # For example, database version, code version, site language, etc.
515 CREATE TABLE `tt_site_config` (
516 `param_name` varchar(32) NOT NULL, # parameter name
517 `param_value` text default NULL, # parameter value
518 `created` datetime default NULL, # creation timestamp
519 `modified` datetime default NULL, # modification timestamp
520 PRIMARY KEY (`param_name`)
523 INSERT INTO `tt_site_config` (`param_name`, `param_value`, `created`) VALUES ('version_db', '1.18.41', now()); # TODO: change when structure changes.