Skip to content

Commit

Permalink
Merge pull request #141 from smallAreaHealthStatisticsUnit/bug/user_n…
Browse files Browse the repository at this point in the history
…ames_mapped_to_lower_case3

Fix case-sensitivity in user names
  • Loading branch information
peterhambly authored Mar 22, 2019
2 parents 848a6d9 + 77e914d commit 8f2a3bd
Show file tree
Hide file tree
Showing 9 changed files with 407 additions and 37 deletions.
32 changes: 31 additions & 1 deletion docs/Installation/QuickstartGuide.md
Original file line number Diff line number Diff line change
Expand Up @@ -15,6 +15,34 @@ Before installing the RIF you must have the following installed:

You must also have administrative rights on the machine on which you are installing.

## Setting the Path

The installation process creates the database schemas used by the RIF, by running a series of SQL scripts. To do so it needs to be able to find the appropriate commands: `psql` for PostgreSQL, and `SQLCMD.EXE` for SQL Server.

To that end you must add the folder containing the appropriate one of those commands to the `PATH` environment variable. If you are unfamiliar with setting environment variables, [you can find instructions here](https://www.computerhope.com/issues/ch000549.htm) for how to do it in various versions of Windows.

The relevant value to add to the path will be something like:

```
C:\Program Files\Microsoft SQL Server\140\Tools\Binn
```

for SQL Server on Windows, or:

```
C:\Program Files\PostgreSQL\9.5\bin
```

for Postgres on Windows, or:

```
/usr/local/bin
```

(which example will almost certainly be on your `PATH` already) for Postgres on other platforms. Exact values will depend on the version of the database system and the specific details of your system.

On Unix-based systems, including Mac and Linux, you can set it in the user's `.profile` or `.bashrc` file, or similar.

## Getting the Installer

Download a RIF installer from the [GitHub site](https://github.com/smallAreaHealthStatisticsUnit/rapidInquiryFacility). We recommend always getting the latest version available from the [Releases tab](https://github.com/smallAreaHealthStatisticsUnit/rapidInquiryFacility/releases).
Expand All @@ -29,7 +57,9 @@ For Windows, save `rifInstaller.exe` to the machine you are installing on. For M

Run the installer from the command line. We don't recommend running it by double-clicking the icon in Windows Explorer or the Finder. It will run, but when it finishes you won't see the output to know whether it was successful.

On Windows, open the Start Menu. Right-click on _Command Prompt_ and choose "Run as administrator". Answer "Yes" to the confirmation dialog.
**Note: On Windows, elevated privileges are needed.**

On Windows, open the Start Menu. Right-click on _Command Prompt_ and choose **"Run as administrator"**. Answer "Yes" to the confirmation dialog.

On Mac, open the _Terminal_ app. On Linux open a terminal.

Expand Down
16 changes: 12 additions & 4 deletions installer/install.py
Original file line number Diff line number Diff line change
Expand Up @@ -103,7 +103,7 @@ def main():
# This sends output to the specified file as well as stdout.
outfile = Tee("install.log")
sys.stdout = outfile
# sys.stderr = outfile
sys.stderr = outfile

# Run SQL scripts
if settings.db_type == "pg":
Expand Down Expand Up @@ -251,10 +251,10 @@ def get_settings():
# Database name is hardcoded for now.
# settings.db_name = get_value_from_user(DATABASE_NAME).strip()
settings.db_name = "sahsuland"
settings.db_user = get_value_from_user(DATABASE_USER,
extra=settings.db_name).strip()
settings.db_user = get_value_from_user(
DATABASE_USER, extra=settings.db_name).strip().lower()
settings.db_pass = get_password_from_user(
DATABASE_PASSWORD, extra=settings.db_user).strip()
DATABASE_PASSWORD, extra=settings.db_user)

# For now the next few are only for Postgres
if settings.db_type == "pg":
Expand Down Expand Up @@ -679,6 +679,14 @@ def set_windows_permissions(file_name):
# complain.
import ntsecuritycon
import win32security
from win32com.shell import shell

# Have to run as an administrator for this bit.
if not shell.IsUserAnAdmin():
banner("This function requires elevated privileges. Please run again "
"from a command prompt started using the 'Run as "
"administrator' feature", 100)
sys.exit(-1)

entries = [{'AccessMode': win32security.GRANT_ACCESS,
'AccessPermissions': 0,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -82,7 +82,14 @@ GRANT SELECT ON rif40_homogeneity TO rif_user, rif_manager;
--
-- Table: rif40.t_rif40_inv_covariates: add covariate_type flag
--
ALTER TABLE rif40.t_rif40_inv_covariates ADD COLUMN IF NOT EXISTS covariate_type character varying(1) NULL;
DO LANGUAGE plpgsql $$
BEGIN
ALTER TABLE rif40.t_rif40_inv_covariates ADD COLUMN covariate_type character varying(1) NULL;
EXCEPTION
WHEN duplicate_column THEN
RAISE NOTICE 'Column already renamed: %',SQLERRM::Text;
END;
$$;

DROP TRIGGER t_rif40_inv_covariates_checks ON rif40.t_rif40_inv_covariates;
UPDATE rif40.t_rif40_inv_covariates
Expand Down
175 changes: 175 additions & 0 deletions rifDatabase/SQLserver/alter scripts/rif40_inv_covariates_trigger.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,175 @@

IF EXISTS (SELECT * FROM sys.triggers tr
INNER JOIN sys.views t ON tr.parent_id = t.object_id
WHERE t.schema_id = SCHEMA_ID(N'rif40')
and tr.name=N'tr_rif40_inv_covariates')
BEGIN
DROP TRIGGER [rif40].[tr_rif40_inv_covariates];
END
GO


------------------------------
-- create trigger code
------------------------------
CREATE trigger [rif40].[tr_rif40_inv_covariates]
on [rif40].[rif40_inv_covariates]
instead of insert , update , delete
as
BEGIN
--------------------------------------
--to Determine the type of transaction
---------------------------------------
DECLARE @XTYPE varchar(1);
IF EXISTS (SELECT * FROM DELETED)
SET @XTYPE = 'D';

IF EXISTS (SELECT * FROM INSERTED)
BEGIN
IF (@XTYPE = 'D')
SET @XTYPE = 'U'
ELSE
SET @XTYPE = 'I'
END;

IF @XTYPE='I'
BEGIN
--
-- Check (USER = NEW.username OR NULL) and USER is a RIF user; if OK INSERT
--
DECLARE @insert_invalid_user VARCHAR(MAX) =
(
select SUSER_SNAME() AS username
from inserted
where NOT (username = SUSER_SNAME() OR username is null)
OR NOT ([rif40].[rif40_has_role](SUSER_SNAME(),'rif_user') = 1
AND [rif40].[rif40_has_role](SUSER_SNAME(),'rif_manager') = 1)
);

IF @insert_invalid_user IS NOT NULL
BEGIN TRY
rollback;
DECLARE @err_msg1 VARCHAR(MAX) = formatmessage(51119, @insert_invalid_user);
THROW 51119, @err_msg1, 1;
END TRY
BEGIN CATCH
EXEC [rif40].[ErrorLog_proc] @Error_Location='[rif40].[rif40_inv_covariates]';
THROW 51119, @err_msg1, 1;
END CATCH;

INSERT INTO [rif40].[t_rif40_inv_covariates] (
username,
study_id,
inv_id,
covariate_name,
covariate_type,
[min],
[max],
geography,
study_geolevel_name)
SELECT
isnull(username,SUSER_SNAME()),
isnull(study_id,[rif40].[rif40_sequence_current_value]('rif40.rif40_study_id_seq')),
isnull(inv_id,[rif40].[rif40_sequence_current_value]('rif40.rif40_inv_id_seq')),
covariate_name /* no default value */,
isnull(covariate_type, 'N'),
[min] /* no default value */,
[max] /* no default value */,
geography /* no default value */,
study_geolevel_name /* no default value */
FROM inserted;

END;

IF @XTYPE='U'
BEGIN
--
-- Check USER = OLD.username and NEW.username = OLD.username; if OK UPDATE
--
DECLARE @update_invalid_user VARCHAR(MAX) =
(
select a.username as 'old_username', b.username as 'new_username', SUSER_SNAME() as 'current_user'
from deleted a
left outer join inserted b on a.study_id=b.study_id AND a.inv_id=b.inv_id AND a.covariate_name=b.covariate_name
where a.username != SUSER_SNAME()
or (b.username is not null and a.username != b.username)
FOR XML PATH ('')
);
IF @update_invalid_user IS NOT NULL
BEGIN TRY
rollback;
DECLARE @err_msg2 VARCHAR(MAX) = formatmessage(51120, @update_invalid_user);
THROW 51120, @err_msg2, 1;
END TRY
BEGIN CATCH
EXEC [rif40].[ErrorLog_proc] @Error_Location='[rif40].[rif40_inv_covariates]';
THROW 51120, @err_msg2, 1;
END CATCH;

DELETE FROM [rif40].[t_rif40_inv_covariates]
WHERE EXISTS (
SELECT 1
FROM deleted b
WHERE b.study_id=[rif40].[t_rif40_inv_covariates].study_id
AND b.inv_id=[rif40].[t_rif40_inv_covariates].inv_id
AND b.covariate_name=[rif40].[t_rif40_inv_covariates].covariate_name);

INSERT INTO [rif40].[t_rif40_inv_covariates] (
username,
study_id,
inv_id,
covariate_name,
covariate_type,
[min],
[max],
geography,
study_geolevel_name)
SELECT
username,
study_id,
inv_id,
covariate_name,
covariate_type,
[min],
[max],
geography,
study_geolevel_name
FROM inserted;

END;

IF @XTYPE='D'
BEGIN
--
-- Check USER = OLD.username; if OK DELETE
--
DECLARE @delete_invalid_user VARCHAR(MAX) =
(
select username
from deleted
where username != SUSER_SNAME()
FOR XML PATH('')
);
IF @delete_invalid_user IS NOT NULL
BEGIN TRY
rollback;
DECLARE @err_msg3 VARCHAR(MAX) = formatmessage(51121, @delete_invalid_user);
THROW 51121, @err_msg3, 1;
END TRY
BEGIN CATCH
EXEC [rif40].[ErrorLog_proc] @Error_Location='[rif40].[rif40_inv_covariates]';
THROW 51121, @err_msg3, 1;
END CATCH;

DELETE FROM [rif40].[t_rif40_inv_covariates]
WHERE EXISTS (
SELECT 1
FROM deleted b
WHERE b.study_id=[rif40].[t_rif40_inv_covariates].study_id
AND b.inv_id=[rif40].[t_rif40_inv_covariates].inv_id
AND b.covariate_name=[rif40].[t_rif40_inv_covariates].covariate_name);

END;

END;
GO
Loading

0 comments on commit 8f2a3bd

Please sign in to comment.