Invalid command, Data type unknown
You can often get this error when creating views with unions. The reason is that Firebird is very strict with datatypes, and when you have different datatype in queries that make up the UNION it throws an error. It can happen even if difference is something trivial like CHAR(5) vs CHAR(6). It also happens for decimal and double datatypes, and (one of the most annoying) when you put NULL or zero. Examples:
create view extreeme_employee (first_name, job_grade)
as
select 'Undisclosed', job_grade
from EMPLOYEE
where job_grade = (select max(job_grade) from EMPLOYEE)
union
select first_name, job_grade
from EMPLOYEE
where job_grade = (select min(job_grade) from EMPLOYEE);
or:
create view extreeme_employee (first_name, job_grade)
as
select first_name, job_grade
from EMPLOYEE
where job_grade = (select max(job_grade) from EMPLOYEE)
union all
select first_name, 0
from EMPLOYEE
where job_grade = 0;
The solution is to cast the value to appropriate datatype, so that all queries return the same datatype for each column.
Firebird 2 has much better type coercion as it detects the largest datatype, and allows smaller ones to fit automatically, i.e. if you have CHAR(5) in one query and CHAR(6) in other, it will automatically set view's column to be CHAR(6). Please note that datatypes have to be compatible for this to work (for example, you cannot union a Blob and Decimal column).