If you ever want to check the parameters submitted with a report for alpha numeric characters (so it doesn't contain symbols, punctuations, etc) then you should do this at the database level, and then get the report to complete the check:
The Plan
- User enters value in parameters and clicks on "View Report"
- Report passes parameter to dataset which gets formatted by the database
- Report retrieves (select) formatted parameter as a field value to use
- Report loads with changes based on returned value.
The Gist
- Add database level parameter check
- Add IIF in SSRS to confirm
Database Level AlphaNumeric Check
You may have better ways to do this but here are my database level checks for alphanumeric values:
-- ORACLE -- 0 if is alphanumeric, 1 or more if not alpha numeric. SELECT (LENGTH(TRIM(TRANSLATE(:ParameterToCheck, 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ0123456789', ' ')))) AS NotAlphaNumeric FROM ... -- Transact-SQL -- 0 if is alphanumeric, 1 or more if not alpha numeric. SELECT PATINDEX('%[^a-zA-Z0-9]%' , @ParameterToCheck) AS NotAlphaNumeric FROM ... -- MySQL -- 1 if is alphanumeric, 0 if not alpha numeric. SELECT @ParameterToCheck REGEXP '^[A-Za-z0-9]+$' AS AlphaNumeric FROM ...
- -- ORACLE
- -- 0 if is alphanumeric, 1 or more if not alpha numeric.
- SELECT
- (LENGTH(TRIM(TRANSLATE(:ParameterToCheck, 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ0123456789', ' ')))) AS NotAlphaNumeric
- FROM
- ...
- -- Transact-SQL
- -- 0 if is alphanumeric, 1 or more if not alpha numeric.
- SELECT
- PATINDEX('%[^a-zA-Z0-9]%' , @ParameterToCheck) AS NotAlphaNumeric
- FROM
- ...
- -- MySQL
- -- 1 if is alphanumeric, 0 if not alpha numeric.
- SELECT
- @ParameterToCheck REGEXP '^[A-Za-z0-9]+$' AS AlphaNumeric
- FROM
- ...
Usage
-- Using the ORACLE example SELECT Column1, Column2, (LENGTH( TRIM( TRANSLATE( :ParameterToCheck, 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ0123456789', ' ' ) ) )) AS NotAlphaNumeric FROM YourDataSetTable WHERE ThisRecord = :UserSpecifiedID -- where :UserSpecifiedID is one of the report parameters (Oracle local variable) -- where :ParameterToCheck is another of the report parameters (Oracle local variable)
- -- Using the ORACLE example
- SELECT
- Column1,
- Column2,
- (LENGTH(
- TRIM(
- TRANSLATE(
- :ParameterToCheck,
- 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ0123456789',
- ' '
- )
- )
- )) AS NotAlphaNumeric
- FROM
- YourDataSetTable
- WHERE
- ThisRecord = :UserSpecifiedID
- -- where :UserSpecifiedID is one of the report parameters (Oracle local variable)
- -- where :ParameterToCheck is another of the report parameters (Oracle local variable)
/* For Expression Value. Remember to apply to both ACTION and if you use color change FONT. Note for MySQL solution change 0 to 1. */ =IIF( Parameters!ParameterToCheck.Value"" AND Fields!NOTALPHANUMERIC.Value=0, "Valid", "Not Valid" )
- /*
- For Expression Value.
- Remember to apply to both ACTION and if you use color change FONT.
- Note for MySQL solution change 0 to 1.
- */
- =IIF(
- Parameters!ParameterToCheck.Value"" AND Fields!NOTALPHANUMERIC.Value=0,
- "Valid",
- "Not Valid"
- )
If like us, you've made a report containing a link dependent on parameters submitted, we had to apply a similar IIF statement block to the Font color and the Action target as well within SSRS.