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_charts,view_own_invoices,view_own_projects,view_own_tasks,manage_own_settings,view_users,track_time,track_expenses,view_reports,view_charts,view_own_clients,override_punch_mode,override_own_punch_mode,override_date_lock,override_own_date_lock,swap_roles,approve_timesheets,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,manage_features,manage_advanced_settings,manage_roles,export_data,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 `email` varchar(100) default NULL, # user email
95 `created` datetime default NULL, # creation timestamp
96 `created_ip` varchar(45) default NULL, # creator ip
97 `created_by` int(11) default NULL, # creator user_id (null for self)
98 `modified` datetime default NULL, # modification timestamp
99 `modified_ip` varchar(45) default NULL, # modifier ip
100 `modified_by` int(11) default NULL, # modifier user_id
101 `accessed` datetime default NULL, # last access timestamp
102 `accessed_ip` varchar(45) default NULL, # last access ip
103 `status` tinyint(4) default 1, # user status
107 # Create an index that guarantees unique active and inactive logins.
108 create unique index login_idx on tt_users(login, status);
110 # Create admin account with password 'secret'. Admin is a superuser who can create groups.
111 DELETE from `tt_users` WHERE login = 'admin';
112 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));
116 # Structure for table tt_projects.
118 CREATE TABLE `tt_projects` (
119 `id` int(11) NOT NULL auto_increment, # project id
120 `group_id` int(11) NOT NULL, # group id
121 `org_id` int(11) default NULL, # organization id
122 `name` varchar(80) COLLATE utf8mb4_bin NOT NULL, # project name
123 `description` varchar(255) default NULL, # project description
124 `tasks` text default NULL, # comma-separated list of task ids associated with this project
125 `status` tinyint(4) default 1, # project status
129 # Create an index that guarantees unique active and inactive projects per group.
130 create unique index project_idx on tt_projects(group_id, name, status);
134 # Structure for table tt_tasks.
136 CREATE TABLE `tt_tasks` (
137 `id` int(11) NOT NULL auto_increment, # task id
138 `group_id` int(11) NOT NULL, # group id
139 `org_id` int(11) default NULL, # organization id
140 `name` varchar(80) COLLATE utf8mb4_bin NOT NULL, # task name
141 `description` varchar(255) default NULL, # task description
142 `status` tinyint(4) default 1, # task status
146 # Create an index that guarantees unique active and inactive tasks per group.
147 create unique index task_idx on tt_tasks(group_id, name, status);
151 # Structure for table tt_user_project_binds. This table maps users to assigned projects.
153 CREATE TABLE `tt_user_project_binds` (
154 `id` int(11) NOT NULL auto_increment, # bind id
155 `user_id` int(11) NOT NULL, # user id
156 `project_id` int(11) NOT NULL, # project id
157 `group_id` int(11) default NULL, # group id
158 `org_id` int(11) default NULL, # organization id
159 `rate` float(6,2) default '0.00', # rate for this user when working on this project
160 `status` tinyint(4) default 1, # bind status
164 # Create an index that guarantees unique user to project binds.
165 create unique index bind_idx on tt_user_project_binds(user_id, project_id);
169 # Structure for table tt_project_task_binds. This table maps projects to assigned tasks.
171 CREATE TABLE `tt_project_task_binds` (
172 `project_id` int(11) NOT NULL, # project id
173 `task_id` int(11) NOT NULL, # task id
174 `group_id` int(11) default NULL, # group id
175 `org_id` int(11) default NULL # organization id
178 # Indexes for tt_project_task_binds.
179 create index project_idx on tt_project_task_binds(project_id);
180 create index task_idx on tt_project_task_binds(task_id);
181 create unique index project_task_idx on tt_project_task_binds(project_id, task_id);
185 # Structure for table tt_log. This is the table where time entries for users are stored.
186 # If you use custom fields, additional info for each record may exist in tt_custom_field_log.
188 CREATE TABLE `tt_log` (
189 `id` bigint NOT NULL auto_increment, # time record id
190 `user_id` int(11) NOT NULL, # user id
191 `group_id` int(11) default NULL, # group id
192 `org_id` int(11) default NULL, # organization id
193 `date` date NOT NULL, # date the record is for
194 `start` time default NULL, # record start time (for example, 09:00)
195 `duration` time default NULL, # record duration (for example, 1 hour)
196 `client_id` int(11) default NULL, # client id
197 `project_id` int(11) default NULL, # project id
198 `task_id` int(11) default NULL, # task id
199 `invoice_id` int(11) default NULL, # invoice id
200 `comment` text, # user provided comment for time record
201 `billable` tinyint(4) default 0, # whether the record is billable or not
202 `paid` tinyint(4) default 0, # whether the record is paid
203 `created` datetime default NULL, # creation timestamp
204 `created_ip` varchar(45) default NULL, # creator ip
205 `created_by` int(11) default NULL, # creator user_id
206 `modified` datetime default NULL, # modification timestamp
207 `modified_ip` varchar(45) default NULL, # modifier ip
208 `modified_by` int(11) default NULL, # modifier user_id
209 `status` tinyint(4) default 1, # time record status
213 # Create indexes on tt_log for performance.
214 create index date_idx on tt_log(date);
215 create index user_idx on tt_log(user_id);
216 create index group_idx on tt_log(group_id);
217 create index client_idx on tt_log(client_id);
218 create index invoice_idx on tt_log(invoice_id);
219 create index project_idx on tt_log(project_id);
220 create index task_idx on tt_log(task_id);
224 # Structure for table tt_invoices. Invoices are issued to clients for billable work.
226 CREATE TABLE `tt_invoices` (
227 `id` int(11) NOT NULL auto_increment, # invoice id
228 `group_id` int(11) NOT NULL, # group id
229 `org_id` int(11) default NULL, # organization id
230 `name` varchar(80) COLLATE utf8mb4_bin NOT NULL, # invoice name
231 `date` date NOT NULL, # invoice date
232 `client_id` int(11) NOT NULL, # client id
233 `status` tinyint(4) default 1, # invoice status
237 # Create an index that guarantees unique invoice names per group.
238 create unique index name_idx on tt_invoices(group_id, name, status);
242 # Structure for table tt_tmp_refs. Used for reset password mechanism.
244 CREATE TABLE `tt_tmp_refs` (
245 `created` datetime default NULL, # creation timestamp
246 `ref` char(32) NOT NULL default '', # unique reference for user, used in urls
247 `user_id` int(11) NOT NULL # user id
252 # Structure for table tt_fav_reports. Favorite reports are pre-configured report configurations.
254 CREATE TABLE `tt_fav_reports` (
255 `id` int(11) NOT NULL auto_increment, # favorite report id
256 `name` varchar(200) NOT NULL, # favorite report name
257 `user_id` int(11) NOT NULL, # user id favorite report belongs to
258 `group_id` int(11) default NULL, # group id
259 `org_id` int(11) default NULL, # organization id
260 `report_spec` text default NULL, # future replacement field for all report settings
261 `client_id` int(11) default NULL, # client id (if selected)
262 `cf_1_option_id` int(11) default NULL, # custom field 1 option id (if selected)
263 `project_id` int(11) default NULL, # project id (if selected)
264 `task_id` int(11) default NULL, # task id (if selected)
265 `billable` tinyint(4) default NULL, # whether to include billable, not billable, or all records
266 `invoice` tinyint(4) default NULL, # whether to include invoiced, not invoiced, or all records
267 `paid_status` tinyint(4) default NULL, # whether to include paid, not paid, or all records
268 `users` text default NULL, # Comma-separated list of user ids. Nothing here means "all" users.
269 `period` tinyint(4) default NULL, # selected period type for report
270 `period_start` date default NULL, # period start
271 `period_end` date default NULL, # period end
272 `show_client` tinyint(4) NOT NULL default 0, # whether to show client column
273 `show_invoice` tinyint(4) NOT NULL default 0, # whether to show invoice column
274 `show_paid` tinyint(4) NOT NULL default 0, # whether to show paid column
275 `show_ip` tinyint(4) NOT NULL default 0, # whether to show ip column
276 `show_project` tinyint(4) NOT NULL default 0, # whether to show project column
277 `show_start` tinyint(4) NOT NULL default 0, # whether to show start field
278 `show_duration` tinyint(4) NOT NULL default 0, # whether to show duration field
279 `show_cost` tinyint(4) NOT NULL default 0, # whether to show cost field
280 `show_task` tinyint(4) NOT NULL default 0, # whether to show task column
281 `show_end` tinyint(4) NOT NULL default 0, # whether to show end field
282 `show_note` tinyint(4) NOT NULL default 0, # whether to show note column
283 `show_custom_field_1` tinyint(4) NOT NULL default 0, # whether to show custom field 1
284 `show_work_units` tinyint(4) NOT NULL default 0, # whether to show work units
285 `show_totals_only` tinyint(4) NOT NULL default 0, # whether to show totals only
286 `group_by1` varchar(20) default NULL, # group by field 1
287 `group_by2` varchar(20) default NULL, # group by field 2
288 `group_by3` varchar(20) default NULL, # group by field 3
289 `status` tinyint(4) default 1, # favorite report status
295 # Structure for table tt_cron. It is used to email favorite reports on schedule.
297 CREATE TABLE `tt_cron` (
298 `id` int(11) NOT NULL auto_increment, # entry id
299 `group_id` int(11) NOT NULL, # group id
300 `org_id` int(11) default NULL, # organization id
301 `cron_spec` varchar(255) NOT NULL, # cron specification, "0 1 * * *" for "daily at 01:00"
302 `last` int(11) default NULL, # UNIX timestamp of when job was last run
303 `next` int(11) default NULL, # UNIX timestamp of when to run next job
304 `report_id` int(11) default NULL, # report id from tt_fav_reports, a report to mail on schedule
305 `email` varchar(100) default NULL, # email to send results to
306 `cc` varchar(100) default NULL, # cc email to send results to
307 `subject` varchar(100) default NULL, # email subject
308 `report_condition` varchar(255) default NULL, # report condition, "count > 0" for sending not empty reports
309 `status` tinyint(4) default 1, # entry status
315 # Structure for table tt_clients. A client is an entity for whom work is performed and who may be invoiced.
317 CREATE TABLE `tt_clients` (
318 `id` int(11) NOT NULL AUTO_INCREMENT, # client id
319 `group_id` int(11) NOT NULL, # group id
320 `org_id` int(11) default NULL, # organization id
321 `name` varchar(80) COLLATE utf8mb4_bin NOT NULL, # client name
322 `address` varchar(255) default NULL, # client address
323 `tax` float(6,2) default '0.00', # applicable tax for this client
324 `projects` text default NULL, # comma-separated list of project ids assigned to this client
325 `status` tinyint(4) default 1, # client status
329 # Create an index that guarantees unique active and inactive clients per group.
330 create unique index client_name_idx on tt_clients(group_id, name, status);
334 # Structure for table tt_client_project_binds. This table maps clients to assigned projects.
336 CREATE TABLE `tt_client_project_binds` (
337 `client_id` int(11) NOT NULL, # client id
338 `project_id` int(11) NOT NULL, # project id
339 `group_id` int(11) default NULL, # group id
340 `org_id` int(11) default NULL # organization id
343 # Indexes for tt_client_project_binds.
344 create index client_idx on tt_client_project_binds(client_id);
345 create index project_idx on tt_client_project_binds(project_id);
346 create unique index client_project_idx on tt_client_project_binds(client_id, project_id);
350 # Structure for table tt_config. This table is used to store configuration info for users.
351 # For example, last_report_email parameter stores an email for user last report was emailed to.
353 CREATE TABLE `tt_config` (
354 `user_id` int(11) NOT NULL, # user id
355 `group_id` int(11) default NULL, # group id
356 `org_id` int(11) default NULL, # organization id
357 `param_name` varchar(32) NOT NULL, # parameter name
358 `param_value` varchar(80) default NULL # parameter value
361 # Create an index that guarantees unique parameter names per user.
362 create unique index param_idx on tt_config(user_id, param_name);
365 # Below are the tables used by CustomFields plugin.
368 # Structure for table tt_custom_fields. This table contains definitions of custom fields.
370 CREATE TABLE `tt_custom_fields` (
371 `id` int(11) NOT NULL auto_increment, # custom field id
372 `group_id` int(11) NOT NULL, # group id
373 `org_id` int(11) default NULL, # organization id
374 `type` tinyint(4) NOT NULL default 0, # custom field type (text or dropdown)
375 `label` varchar(32) NOT NULL default '', # custom field label
376 `required` tinyint(4) default 0, # whether this custom field is mandatory for time records
377 `status` tinyint(4) default 1, # custom field status
383 # Structure for table tt_custom_field_options. This table defines options for dropdown custom fields.
385 CREATE TABLE `tt_custom_field_options` (
386 `id` int(11) NOT NULL auto_increment, # option id
387 `group_id` int(11) default NULL, # group id
388 `org_id` int(11) default NULL, # organization id
389 `field_id` int(11) NOT NULL, # custom field id
390 `value` varchar(32) NOT NULL default '', # option value
391 `status` tinyint(4) default 1, # option status
397 # Structure for table tt_custom_field_log.
398 # This table supplements tt_log and contains custom field values for records.
400 CREATE TABLE `tt_custom_field_log` (
401 `id` bigint NOT NULL auto_increment, # custom field log id
402 `group_id` int(11) default NULL, # group id
403 `org_id` int(11) default NULL, # organization id
404 `log_id` bigint NOT NULL, # id of a record in tt_log this record corresponds to
405 `field_id` int(11) NOT NULL, # custom field id
406 `option_id` int(11) default NULL, # Option id. Used for dropdown custom fields.
407 `value` varchar(255) default NULL, # Text value. Used for text custom fields.
408 `status` tinyint(4) default 1, # custom field log entry status
412 create index log_idx on tt_custom_field_log(log_id);
416 # Structure for table tt_expense_items.
417 # This table lists expense items.
419 CREATE TABLE `tt_expense_items` (
420 `id` bigint NOT NULL auto_increment, # expense item id
421 `date` date NOT NULL, # date the record is for
422 `user_id` int(11) NOT NULL, # user id the expense item is reported by
423 `group_id` int(11) default NULL, # group id
424 `org_id` int(11) default NULL, # organization id
425 `client_id` int(11) default NULL, # client id
426 `project_id` int(11) default NULL, # project id
427 `name` text NOT NULL, # expense item name (what is an expense for)
428 `cost` decimal(10,2) default '0.00', # item cost (including taxes, etc.)
429 `invoice_id` int(11) default NULL, # invoice id
430 `paid` tinyint(4) default 0, # whether the item is paid
431 `created` datetime default NULL, # creation timestamp
432 `created_ip` varchar(45) default NULL, # creator ip
433 `created_by` int(11) default NULL, # creator user_id
434 `modified` datetime default NULL, # modification timestamp
435 `modified_ip` varchar(45) default NULL, # modifier ip
436 `modified_by` int(11) default NULL, # modifier user_id
437 `status` tinyint(4) default 1, # item status
441 # Create indexes on tt_expense_items for performance.
442 create index date_idx on tt_expense_items(date);
443 create index user_idx on tt_expense_items(user_id);
444 create index group_idx on tt_expense_items(group_id);
445 create index client_idx on tt_expense_items(client_id);
446 create index project_idx on tt_expense_items(project_id);
447 create index invoice_idx on tt_expense_items(invoice_id);
451 # Structure for table tt_predefined_expenses.
452 # This table keeps names and costs for predefined expenses.
454 CREATE TABLE `tt_predefined_expenses` (
455 `id` int(11) NOT NULL auto_increment, # predefined expense id
456 `group_id` int(11) NOT NULL, # group id
457 `org_id` int(11) default NULL, # organization id
458 `name` varchar(255) NOT NULL, # predefined expense name, such as mileage
459 `cost` decimal(10,2) default '0.00', # cost for one unit
465 # Structure for table tt_monthly_quotas.
466 # This table keeps monthly work hour quotas for groups.
468 CREATE TABLE `tt_monthly_quotas` (
469 `group_id` int(11) NOT NULL, # group id
470 `org_id` int(11) default NULL, # organization id
471 `year` smallint(5) UNSIGNED NOT NULL, # quota year
472 `month` tinyint(3) UNSIGNED NOT NULL, # quota month
473 `minutes` int(11) default NULL, # quota in minutes in specified month and year
474 PRIMARY KEY (`group_id`,`year`,`month`)
479 # Structure for table tt_site_config. This table stores configuration data
480 # for Time Tracker site as a whole.
481 # For example, database version, code version, site language, etc.
483 CREATE TABLE `tt_site_config` (
484 `param_name` varchar(32) NOT NULL, # parameter name
485 `param_value` text default NULL, # parameter value
486 `created` datetime default NULL, # creation timestamp
487 `modified` datetime default NULL, # modification timestamp
488 PRIMARY KEY (`param_name`)
491 INSERT INTO `tt_site_config` (`param_name`, `param_value`, `created`) VALUES ('version_db', '1.18.26', now()); # TODO: change when structure changes.