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 default CURRENT_TIMESTAMP, # modification timestamp
18 `name` varchar(80) default NULL, # team name
19 `currency` varchar(7) default NULL, # team currency symbol
20 `decimal_mark` char(1) NOT NULL default '.', # separator in decimals
21 `lang` varchar(10) NOT NULL default 'en', # language
22 `date_format` varchar(20) NOT NULL default '%Y-%m-%d', # date format
23 `time_format` varchar(20) NOT NULL default '%H:%M', # time format
24 `week_start` smallint(2) NOT NULL default 0, # Week start day, 0 == Sunday.
25 `tracking_mode` smallint(2) NOT NULL default 1, # tracking mode ("time", "projects" or "projects and tasks")
26 `project_required` smallint(2) NOT NULL default 0, # whether a project selection is required or optional
27 `task_required` smallint(2) NOT NULL default 0, # whether a task selection is required or optional
28 `record_type` smallint(2) NOT NULL default 0, # time record type ("start and finish", "duration", or both)
29 `bcc_email` varchar(100) default NULL, # bcc email to copy all reports to
30 `plugins` varchar(255) default NULL, # a list of enabled plugins for team
31 `lock_spec` varchar(255) default NULL, # Cron specification for record locking,
32 # for example: "0 10 * * 1" for "weekly on Mon at 10:00".
33 `workday_minutes` smallint(4) default 480, # number of work minutes in a regular working day
34 `custom_logo` tinyint(4) default 0, # whether to use a custom logo or not
35 `config` text default NULL, # miscellaneous team configuration settings
36 `status` tinyint(4) default 1, # team status
42 # Structure for table tt_roles. This table stores customized team roles.
44 CREATE TABLE `tt_roles` (
45 `id` int(11) NOT NULL auto_increment, # Role id. Identifies roles for all groups on the server.
46 `team_id` int(11) NOT NULL, # Team id the role is defined for.
47 `name` varchar(80) default NULL, # Role name - custom role name. In case we are editing a
48 # predefined role (USER, etc.), we can rename the role here.
49 `description` varchar(255) default NULL, # Role description.
50 `rank` int(11) default 0, # Role rank, an integer value between 0-324. Predefined role ranks:
51 # USER - 4, CLIENT - 16, COMANAGER - 68, MANAGER - 324.
52 # Rank is used to determine what "lesser roles" are in each group
53 # for sutuations such as "manage_users".
54 # It also identifies a role within a team (by its "rank").
55 # Value of rank is to be used in role field in tt_users table,
56 # just like standard roles now.
57 `rights` text default NULL, # Comma-separated list of rights assigned to a role.
58 # NULL here for predefined roles (4, 16, 68, 324 - manager)
59 # means a hard-coded set of default access rights.
60 `status` tinyint(4) default 1, # Role status.
64 # Create an index that guarantees unique active and inactive role ranks in each group.
65 create unique index role_idx on tt_roles(team_id, rank, status);
67 # Insert site-wide roles - site administrator and top manager.
68 INSERT INTO `tt_roles` (`team_id`, `name`, `rank`, `rights`) VALUES (0, 'Site administrator', 1024, 'administer_site');
69 INSERT INTO `tt_roles` (`team_id`, `name`, `rank`, `rights`) VALUES (0, 'Top manager', 512, 'track_own_time,track_own_expenses,view_own_reports,view_own_charts,view_own_invoices,manage_own_settings,view_users,track_time,track_expenses,view_reports,view_charts,override_punch_mode,override_date_lock,swap_roles,approve_timesheets,manage_users,manage_projects,manage_tasks,manage_custom_fields,manage_clients,manage_invoices,manage_features,manage_basic_settings,manage_advanced_settings,manage_roles,export_data,manage_subgroups');
73 # Structure for table tt_users. This table is used to store user properties.
75 CREATE TABLE `tt_users` (
76 `id` int(11) NOT NULL auto_increment, # user id
77 `timestamp` timestamp default CURRENT_TIMESTAMP, # modification timestamp
78 `login` varchar(50) COLLATE utf8_bin NOT NULL, # user login
79 `password` varchar(50) default NULL, # password hash
80 `name` varchar(100) default NULL, # user name
81 `team_id` int(11) NOT NULL, # team id
82 `role` int(11) default 4, # user role ("manager", "co-manager", "client", or "user")
83 `role_id` int(11) default NULL, # future replacement of role
84 `client_id` int(11) default NULL, # client id for "client" user role
85 `rate` float(6,2) NOT NULL default '0.00', # default hourly rate
86 `email` varchar(100) default NULL, # user email
87 `status` tinyint(4) default 1, # user status
91 # Create an index that guarantees unique active and inactive logins.
92 create unique index login_idx on tt_users(login, status);
94 # Create admin account with password 'secret'. Admin is a superuser, who can create teams.
95 DELETE from `tt_users` WHERE login = 'admin';
96 INSERT INTO `tt_users` (`login`, `password`, `name`, `team_id`, `role`, `role_id`) VALUES ('admin', md5('secret'), 'Admin', '0', '1024', (select id from tt_roles where rank = 1024));
100 # Structure for table tt_projects.
102 CREATE TABLE `tt_projects` (
103 `id` int(11) NOT NULL auto_increment, # project id
104 `team_id` int(11) NOT NULL, # team id
105 `name` varchar(80) COLLATE utf8_bin NOT NULL, # project name
106 `description` varchar(255) default NULL, # project description
107 `tasks` text default NULL, # comma-separated list of task ids associated with this project
108 `status` tinyint(4) default 1, # project status
112 # Create an index that guarantees unique active and inactive projects per team.
113 create unique index project_idx on tt_projects(team_id, name, status);
117 # Structure for table tt_tasks.
119 CREATE TABLE `tt_tasks` (
120 `id` int(11) NOT NULL auto_increment, # task id
121 `team_id` int(11) NOT NULL, # team id
122 `name` varchar(80) COLLATE utf8_bin NOT NULL, # task name
123 `description` varchar(255) default NULL, # task description
124 `status` tinyint(4) default 1, # task status
128 # Create an index that guarantees unique active and inactive tasks per team.
129 create unique index task_idx on tt_tasks(team_id, name, status);
133 # Structure for table tt_user_project_binds. This table maps users to assigned projects.
135 CREATE TABLE `tt_user_project_binds` (
136 `id` int(11) NOT NULL auto_increment, # bind id
137 `user_id` int(11) NOT NULL, # user id
138 `project_id` int(11) NOT NULL, # project id
139 `rate` float(6,2) default '0.00', # rate for this user when working on this project
140 `status` tinyint(4) default 1, # bind status
144 # Create an index that guarantees unique user to project binds.
145 create unique index bind_idx on tt_user_project_binds(user_id, project_id);
149 # Structure for table tt_project_task_binds. This table maps projects to assigned tasks.
151 CREATE TABLE `tt_project_task_binds` (
152 `project_id` int(11) NOT NULL, # project id
153 `task_id` int(11) NOT NULL # task id
156 # Indexes for tt_project_task_binds.
157 create index project_idx on tt_project_task_binds(project_id);
158 create index task_idx on tt_project_task_binds(task_id);
162 # Structure for table tt_log. This is the table where time entries for users are stored.
163 # If you use custom fields, additional info for each record may exist in tt_custom_field_log.
165 CREATE TABLE `tt_log` (
166 `id` bigint NOT NULL auto_increment, # time record id
167 `timestamp` timestamp default CURRENT_TIMESTAMP, # modification timestamp
168 `user_id` int(11) NOT NULL, # user id
169 `date` date NOT NULL, # date the record is for
170 `start` time default NULL, # record start time (for example, 09:00)
171 `duration` time default NULL, # record duration (for example, 1 hour)
172 `client_id` int(11) default NULL, # client id
173 `project_id` int(11) default NULL, # project id
174 `task_id` int(11) default NULL, # task id
175 `invoice_id` int(11) default NULL, # invoice id
176 `comment` text, # user provided comment for time record
177 `billable` tinyint(4) default 0, # whether the record is billable or not
178 `paid` tinyint(4) default 0, # whether the record is paid
179 `status` tinyint(4) default 1, # time record status
183 # Create indexes on tt_log for performance.
184 create index date_idx on tt_log(date);
185 create index user_idx on tt_log(user_id);
186 create index client_idx on tt_log(client_id);
187 create index invoice_idx on tt_log(invoice_id);
188 create index project_idx on tt_log(project_id);
189 create index task_idx on tt_log(task_id);
193 # Structure for table tt_invoices. Invoices are issued to clients for billable work.
195 CREATE TABLE `tt_invoices` (
196 `id` int(11) NOT NULL auto_increment, # invoice id
197 `team_id` int(11) NOT NULL, # team id
198 `name` varchar(80) COLLATE utf8_bin NOT NULL, # invoice name
199 `date` date NOT NULL, # invoice date
200 `client_id` int(11) NOT NULL, # client id
201 `status` tinyint(4) default 1, # invoice status
205 # Create an index that guarantees unique invoice names per team.
206 create unique index name_idx on tt_invoices(team_id, name, status);
210 # Structure for table tt_tmp_refs. Used for reset password mechanism.
212 CREATE TABLE `tt_tmp_refs` (
213 `timestamp` timestamp default CURRENT_TIMESTAMP, # creation timestamp
214 `ref` char(32) NOT NULL default '', # unique reference for user, used in urls
215 `user_id` int(11) NOT NULL # user id
220 # Structure for table tt_fav_reports. Favorite reports are pre-configured report configurations.
222 CREATE TABLE `tt_fav_reports` (
223 `id` int(11) NOT NULL auto_increment, # favorite report id
224 `name` varchar(200) NOT NULL, # favorite report name
225 `user_id` int(11) NOT NULL, # user id favorite report belongs to
226 `report_spec` text default NULL, # future replacement field for all report settings
227 `client_id` int(11) default NULL, # client id (if selected)
228 `cf_1_option_id` int(11) default NULL, # custom field 1 option id (if selected)
229 `project_id` int(11) default NULL, # project id (if selected)
230 `task_id` int(11) default NULL, # task id (if selected)
231 `billable` tinyint(4) default NULL, # whether to include billable, not billable, or all records
232 `invoice` tinyint(4) default NULL, # whether to include invoiced, not invoiced, or all records
233 `paid_status` tinyint(4) default NULL, # whether to include paid, not paid, or all records
234 `users` text default NULL, # Comma-separated list of user ids. Nothing here means "all" users.
235 `period` tinyint(4) default NULL, # selected period type for report
236 `period_start` date default NULL, # period start
237 `period_end` date default NULL, # period end
238 `show_client` tinyint(4) NOT NULL default 0, # whether to show client column
239 `show_invoice` tinyint(4) NOT NULL default 0, # whether to show invoice column
240 `show_paid` tinyint(4) NOT NULL default 0, # whether to show paid column
241 `show_project` tinyint(4) NOT NULL default 0, # whether to show project column
242 `show_start` tinyint(4) NOT NULL default 0, # whether to show start field
243 `show_duration` tinyint(4) NOT NULL default 0, # whether to show duration field
244 `show_cost` tinyint(4) NOT NULL default 0, # whether to show cost field
245 `show_task` tinyint(4) NOT NULL default 0, # whether to show task column
246 `show_end` tinyint(4) NOT NULL default 0, # whether to show end field
247 `show_note` tinyint(4) NOT NULL default 0, # whether to show note column
248 `show_custom_field_1` tinyint(4) NOT NULL default 0, # whether to show custom field 1
249 `show_totals_only` tinyint(4) NOT NULL default 0, # whether to show totals only
250 `group_by` varchar(20) default NULL, # group by field
251 `status` tinyint(4) default 1, # favorite report status
257 # Structure for table tt_cron. It is used to email favorite reports on schedule.
259 CREATE TABLE `tt_cron` (
260 `id` int(11) NOT NULL auto_increment, # entry id
261 `team_id` int(11) NOT NULL, # team id
262 `cron_spec` varchar(255) NOT NULL, # cron specification, "0 1 * * *" for "daily at 01:00"
263 `last` int(11) default NULL, # UNIX timestamp of when job was last run
264 `next` int(11) default NULL, # UNIX timestamp of when to run next job
265 `report_id` int(11) default NULL, # report id from tt_fav_reports, a report to mail on schedule
266 `email` varchar(100) default NULL, # email to send results to
267 `cc` varchar(100) default NULL, # cc email to send results to
268 `subject` varchar(100) default NULL, # email subject
269 `report_condition` varchar(255) default NULL, # report condition, "count > 0" for sending not empty reports
270 `status` tinyint(4) default 1, # entry status
276 # Structure for table tt_clients. A client is an entity for whom work is performed and who may be invoiced.
278 CREATE TABLE `tt_clients` (
279 `id` int(11) NOT NULL AUTO_INCREMENT, # client id
280 `team_id` int(11) NOT NULL, # team id
281 `name` varchar(80) COLLATE utf8_bin NOT NULL, # client name
282 `address` varchar(255) default NULL, # client address
283 `tax` float(6,2) default '0.00', # applicable tax for this client
284 `projects` text default NULL, # comma-separated list of project ids assigned to this client
285 `status` tinyint(4) default 1, # client status
289 # Create an index that guarantees unique active and inactive clients per team.
290 create unique index client_name_idx on tt_clients(team_id, name, status);
294 # Structure for table tt_client_project_binds. This table maps clients to assigned projects.
296 CREATE TABLE `tt_client_project_binds` (
297 `client_id` int(11) NOT NULL, # client id
298 `project_id` int(11) NOT NULL # project id
301 # Indexes for tt_client_project_binds.
302 create index client_idx on tt_client_project_binds(client_id);
303 create index project_idx on tt_client_project_binds(project_id);
307 # Structure for table tt_config. This table is used to store configuration info for users.
308 # For example, last_report_email parameter stores an email for user last report was emailed to.
310 CREATE TABLE `tt_config` (
311 `user_id` int(11) NOT NULL, # user id
312 `param_name` varchar(32) NOT NULL, # parameter name
313 `param_value` varchar(80) default NULL # parameter value
316 # Create an index that guarantees unique parameter names per user.
317 create unique index param_idx on tt_config(user_id, param_name);
320 # Below are the tables used by CustomFields plugin.
323 # Structure for table tt_custom_fields. This table contains definitions of custom fields.
325 CREATE TABLE `tt_custom_fields` (
326 `id` int(11) NOT NULL auto_increment, # custom field id
327 `team_id` int(11) NOT NULL, # team id
328 `type` tinyint(4) NOT NULL default 0, # custom field type (text or dropdown)
329 `label` varchar(32) NOT NULL default '', # custom field label
330 `required` tinyint(4) default 0, # whether this custom field is mandatory for time records
331 `status` tinyint(4) default 1, # custom field status
337 # Structure for table tt_custom_field_options. This table defines options for dropdown custom fields.
339 CREATE TABLE `tt_custom_field_options` (
340 `id` int(11) NOT NULL auto_increment, # option id
341 `field_id` int(11) NOT NULL, # custom field id
342 `value` varchar(32) NOT NULL default '', # option value
348 # Structure for table tt_custom_field_log.
349 # This table supplements tt_log and contains custom field values for records.
351 CREATE TABLE `tt_custom_field_log` (
352 `id` bigint NOT NULL auto_increment, # cutom field log id
353 `log_id` bigint NOT NULL, # id of a record in tt_log this record corresponds to
354 `field_id` int(11) NOT NULL, # custom field id
355 `option_id` int(11) default NULL, # Option id. Used for dropdown custom fields.
356 `value` varchar(255) default NULL, # Text value. Used for text custom fields.
357 `status` tinyint(4) default 1, # custom field log entry status
363 # Structure for table tt_expense_items.
364 # This table lists expense items.
366 CREATE TABLE `tt_expense_items` (
367 `id` bigint NOT NULL auto_increment, # expense item id
368 `date` date NOT NULL, # date the record is for
369 `user_id` int(11) NOT NULL, # user id the expense item is reported by
370 `client_id` int(11) default NULL, # client id
371 `project_id` int(11) default NULL, # project id
372 `name` text NOT NULL, # expense item name (what is an expense for)
373 `cost` decimal(10,2) default '0.00', # item cost (including taxes, etc.)
374 `invoice_id` int(11) default NULL, # invoice id
375 `paid` tinyint(4) default 0, # whether the item is paid
376 `status` tinyint(4) default 1, # item status
380 # Create indexes on tt_expense_items for performance.
381 create index date_idx on tt_expense_items(date);
382 create index user_idx on tt_expense_items(user_id);
383 create index client_idx on tt_expense_items(client_id);
384 create index project_idx on tt_expense_items(project_id);
385 create index invoice_idx on tt_expense_items(invoice_id);
389 # Structure for table tt_predefined_expenses.
390 # This table keeps names and costs for predefined expenses.
392 CREATE TABLE `tt_predefined_expenses` (
393 `id` int(11) NOT NULL auto_increment, # predefined expense id
394 `team_id` int(11) NOT NULL, # team id
395 `name` varchar(255) NOT NULL, # predefined expense name, such as mileage
396 `cost` decimal(10,2) default '0.00', # cost for one unit
402 # Structure for table tt_monthly_quotas.
403 # This table keeps monthly work hour quotas for teams.
405 CREATE TABLE `tt_monthly_quotas` (
406 `team_id` int(11) NOT NULL, # team id
407 `year` smallint(5) UNSIGNED NOT NULL, # quota year
408 `month` tinyint(3) UNSIGNED NOT NULL, # quota month
409 `minutes` int(11) default NULL, # quota in minutes in specified month and year
410 PRIMARY KEY (`team_id`,`year`,`month`)
413 ALTER TABLE `tt_monthly_quotas`
414 ADD CONSTRAINT `FK_TT_TEAM_CONSTRAING` FOREIGN KEY (`team_id`) REFERENCES `tt_teams` (`id`) ON DELETE CASCADE ON UPDATE CASCADE;
418 # Structure for table tt_site_config. This table stores configuration data
419 # for Time Tracker site as a whole.
420 # For example, database version, code version, site language, etc.
422 CREATE TABLE `tt_site_config` (
423 `param_name` varchar(32) NOT NULL, # parameter name
424 `param_value` text default NULL, # parameter value
425 `created` datetime default NULL, # creation time
426 `updated` datetime default NULL, # modification time
427 PRIMARY KEY (`param_name`)
430 INSERT INTO `tt_site_config` (`param_name`, `param_value`, `created`) VALUES ('version_db', '1.17.44', now()); # TODO: change when structure changes.